-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
feat(dour_des_comptes): revert deletion
- Loading branch information
1 parent
4f52ab7
commit 72fc185
Showing
4 changed files
with
187 additions
and
0 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
76 changes: 76 additions & 0 deletions
76
projects/cour_des_comptes/models/intermediate/users/int_users.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,76 @@ | ||
WITH users_with_date_of_birth AS ( | ||
SELECT | ||
decidim_users.id, | ||
decidim_users.email, | ||
decidim_users.sign_in_count, | ||
(CASE | ||
WHEN decidim_users.sign_in_count = 0 THEN 'Jamais' | ||
WHEN decidim_users.sign_in_count = 1 THEN 'Une seule fois' | ||
WHEN decidim_users.sign_in_count = 2 THEN 'Deux fois' | ||
WHEN decidim_users.sign_in_count BETWEEN 2 AND 10 THEN 'Entre 2 et 10 fois' | ||
ELSE 'Plus de 10 fois' | ||
END | ||
) AS sign_in_frequency, | ||
decidim_users.last_sign_in_at, | ||
decidim_users.created_at, | ||
decidim_users.updated_at, | ||
decidim_users.invitation_created_at, | ||
decidim_users.invitation_sent_at, | ||
decidim_users.invitation_accepted_at, | ||
decidim_users.invited_by_id, | ||
decidim_users.invited_by_type, | ||
decidim_users.decidim_organization_id, | ||
decidim_users.confirmed_at, | ||
decidim_users.confirmation_token, | ||
decidim_users.unconfirmed_email, | ||
decidim_users.name, | ||
decidim_users.locale, | ||
decidim_users.deleted_at, | ||
decidim_users.admin, | ||
decidim_users.managed, | ||
decidim_users.roles, | ||
decidim_users.nickname, | ||
decidim_users.accepted_tos_version, | ||
decidim_users.type, | ||
decidim_users.following_count, | ||
decidim_users.followers_count, | ||
decidim_users.failed_attempts, | ||
decidim_users.locked_at, | ||
decidim_users.admin_terms_accepted_at, | ||
decidim_users.blocked, | ||
decidim_users.blocked_at, | ||
(CASE WHEN decidim_users.confirmed_at IS NULL THEN false ELSE true END) AS confirmed, | ||
decidim_users.extended_data, | ||
decidim_users.extended_data::jsonb->>'date_of_birth' as date_of_birth | ||
FROM {{ ref ("stg_decidim_users")}} as decidim_users | ||
WHERE deleted_at IS NULL | ||
AND type LIKE 'Decidim::User' | ||
), | ||
|
||
users_with_age AS ( | ||
SELECT | ||
*, | ||
EXTRACT(YEAR FROM AGE(CURRENT_DATE, DATE(users_with_date_of_birth.date_of_birth))) AS age | ||
FROM users_with_date_of_birth | ||
) | ||
|
||
SELECT | ||
*, | ||
(CASE | ||
when age < 15 then '[0-15 ans]' | ||
when age >= 15 and age <= 19 then '[15-19 ans]' | ||
when age >= 20 and age <= 24 then '[20-24 ans]' | ||
when age >= 25 and age <= 29 then '[25-29 ans]' | ||
when age >= 30 and age <= 34 then '[30-34 ans]' | ||
when age >= 35 and age <= 39 then '[35-39 ans]' | ||
when age >= 40 and age <= 44 then '[40-44 ans]' | ||
when age >= 45 and age <= 49 then '[45-49 ans]' | ||
when age >= 50 and age <= 54 then '[50-54 ans]' | ||
when age >= 55 and age <= 59 then '[55-59 ans]' | ||
when age >= 60 and age <= 64 then '[60-64 ans]' | ||
when age >= 65 and age <= 69 then '[65-69 ans]' | ||
when age >= 70 and age <= 74 then '[70-74 ans]' | ||
when age >= 75 then '[75 ans ou plus]' | ||
else 'Âge non défini' | ||
end) as age_category | ||
FROM users_with_age |
22 changes: 22 additions & 0 deletions
22
projects/cour_des_comptes/models/intermediate/users/schema.yml
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,22 @@ | ||
unit_tests: | ||
|
||
- name: testing_that_extended_age_data_matches_age_categories | ||
description: "Checks that age matching fetches the correct infos " | ||
model: int_users | ||
given: | ||
- input: ref('stg_decidim_users') | ||
format: dict | ||
rows: | ||
- {id: 1, extended_data: '{"date_of_birth": "1955-11-06"}', type: 'Decidim::User'} | ||
- {id: 2, extended_data: '{"date_of_birth": "1970-06-23"}', type: 'Decidim::User'} | ||
- {id: 3, extended_data: '{"date_of_birth": "1932-05-23"}', type: 'Decidim::User'} | ||
- {id: 4, extended_data: '{"date_of_birth": "2009-12-01"}', type: 'Decidim::User'} | ||
- {id: 5, extended_data: null, type: 'Decidim::User'} | ||
expect: | ||
format: dict | ||
rows: | ||
- {id: 1, date_of_birth: "1955-11-06", age: 68, age_category: "[65-69 ans]"} | ||
- {id: 2, date_of_birth: "1970-06-23", age: 54, age_category: "[50-54 ans]"} | ||
- {id: 3, date_of_birth: "1932-05-23", age: 92, age_category: "[75 ans ou plus]"} | ||
- {id: 4, date_of_birth: "2009-12-01", age: 14, age_category: "[0-15 ans]"} | ||
- {id: 5, date_of_birth: null, age: null, age_category: 'Âge non défini'} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,79 @@ | ||
WITH followings AS ( | ||
SELECT DISTINCT | ||
decidim_user_id | ||
FROM {{ ref("followings")}} | ||
), participations_proposals AS ( | ||
SELECT decidim_coauthorships.decidim_author_id | ||
FROM {{ ref("proposals")}} AS decidim_proposals_proposals | ||
JOIN {{ ref("stg_decidim_coauthorships")}} AS decidim_coauthorships ON decidim_coauthorships.coauthorable_id = decidim_proposals_proposals.id | ||
WHERE coauthorable_type = 'Decidim::Proposals::Proposal' | ||
), participations AS ( | ||
SELECT | ||
decidim_users.id AS user_id, | ||
MAX(CASE WHEN decidim_endorsements.decidim_author_id IS NOT NULL THEN 1 ELSE 0 END) = 1 AS is_endorsing, | ||
MAX(CASE WHEN decidim_comments.decidim_author_id IS NOT NULL THEN 1 ELSE 0 END) = 1 AS has_authored_comment, | ||
MAX(CASE WHEN decidim_forms_answers.decidim_user_id IS NOT NULL THEN 1 ELSE 0 END) = 1 AS has_answered_survey, | ||
MAX(CASE WHEN decidim_proposals_proposal_votes.decidim_author_id IS NOT NULL THEN 1 ELSE 0 END) = 1 AS has_voted_on_proposal, | ||
MAX(CASE WHEN decidim_budgets_projects_votes.decidim_user_id IS NOT NULL THEN 1 ELSE 0 END) = 1 AS has_voted_on_project, | ||
MAX(CASE WHEN participations_proposals.decidim_author_id IS NOT NULL THEN 1 ELSE 0 END) = 1 AS has_authored_proposal | ||
FROM {{ ref("int_users")}} AS decidim_users | ||
LEFT JOIN {{ ref("endorsements")}} AS decidim_endorsements ON decidim_users.id = decidim_endorsements.decidim_author_id | ||
LEFT JOIN {{ ref("comments")}} AS decidim_comments ON decidim_users.id = decidim_comments.decidim_author_id | ||
LEFT JOIN {{ ref("forms_answers")}} AS decidim_forms_answers ON decidim_users.id = decidim_forms_answers.decidim_user_id | ||
LEFT JOIN {{ ref("proposals_votes")}} AS decidim_proposals_proposal_votes ON decidim_users.id = decidim_proposals_proposal_votes.decidim_author_id | ||
LEFT JOIN {{ ref("projects_votes")}} AS decidim_budgets_projects_votes ON decidim_users.id = decidim_budgets_projects_votes.decidim_user_id | ||
LEFT JOIN participations_proposals ON decidim_users.id = participations_proposals.decidim_author_id | ||
GROUP BY decidim_users.id | ||
) | ||
|
||
SELECT | ||
decidim_users.id, | ||
decidim_users.email, | ||
decidim_users.sign_in_count, | ||
decidim_users.sign_in_frequency, | ||
decidim_users.last_sign_in_at, | ||
decidim_users.created_at, | ||
decidim_users.updated_at, | ||
decidim_users.invitation_created_at, | ||
decidim_users.invitation_sent_at, | ||
decidim_users.invitation_accepted_at, | ||
decidim_users.invited_by_id, | ||
decidim_users.invited_by_type, | ||
decidim_users.decidim_organization_id, | ||
decidim_users.confirmed_at, | ||
decidim_users.confirmation_token, | ||
decidim_users.unconfirmed_email, | ||
decidim_users.name, | ||
decidim_users.locale, | ||
decidim_users.deleted_at, | ||
decidim_users.admin, | ||
decidim_users.managed, | ||
decidim_users.roles, | ||
decidim_users.nickname, | ||
decidim_users.accepted_tos_version, | ||
decidim_users.type, | ||
decidim_users.following_count, | ||
decidim_users.followers_count, | ||
decidim_users.failed_attempts, | ||
decidim_users.locked_at, | ||
decidim_users.admin_terms_accepted_at, | ||
decidim_users.blocked, | ||
decidim_users.blocked_at, | ||
COALESCE(participations.is_endorsing, false) is_endorsing, | ||
(CASE WHEN followings.decidim_user_id IS NULL THEN false ELSE true END) AS is_following, | ||
COALESCE(participations.has_authored_comment, false) has_authored_comment, | ||
COALESCE(participations.has_voted_on_proposal, false) has_voted_on_proposal, | ||
COALESCE(participations.has_voted_on_project, false) has_voted_on_project, | ||
COALESCE(participations.has_authored_proposal, false) has_authored_proposal, | ||
COALESCE(participations.has_answered_survey, false) has_answered_survey, | ||
decidim_users.confirmed, | ||
concat('https://', decidim_organizations.host, '/profiles/', decidim_users.nickname, '/activity') as url, | ||
decidim_users.extended_data, | ||
decidim_users.date_of_birth, | ||
decidim_users.age, | ||
decidim_users.age_category | ||
FROM {{ ref ("int_users")}} as decidim_users | ||
LEFT JOIN followings on followings.decidim_user_id = decidim_users.id | ||
LEFT JOIN participations ON participations.user_id = decidim_users.id | ||
JOIN {{ ref ("int_organizations")}} as decidim_organizations on decidim_organizations.id = decidim_users.decidim_organization_id | ||
WHERE true |