Skip to content

Commit

Permalink
Merge pull request #2 from OpenSourcePolitics/add_extended_data_to_users
Browse files Browse the repository at this point in the history
feat(cdc): adding extended data parsed date of birth in users + fix
  • Loading branch information
Fujistone authored Aug 29, 2024
2 parents 03efb1a + 489c635 commit 2f06460
Show file tree
Hide file tree
Showing 6 changed files with 239 additions and 3 deletions.
5 changes: 2 additions & 3 deletions .gitignore
Original file line number Diff line number Diff line change
@@ -1,8 +1,7 @@
.vscode/

.user.yml
.env
.idea
.DS_Store

package-lock.yml
package-lock.yml
logs/
14 changes: 14 additions & 0 deletions projects/cour_des_comptes/dbt_project.yml
Original file line number Diff line number Diff line change
Expand Up @@ -29,6 +29,20 @@ clean-targets: # directories to be removed by `dbt clean`
# directory as views. These settings can be overridden in the individual model
# files using the `{{ config(...) }}` macro.
models:
demo:
staging:
decidim:
stg_decidim_users:
+enabled: false
intermediate:
users:
int_users:
+enabled: false
marts:
users:
users:
+enabled: false

cour_des_comptes:
# Config indicated by + and applies to all files under models/example/
example:
Expand Down
77 changes: 77 additions & 0 deletions projects/cour_des_comptes/models/intermediate/users/int_users.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,77 @@
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.email_on_notification,
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
24 changes: 24 additions & 0 deletions projects/cour_des_comptes/models/intermediate/users/schema.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,24 @@
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'}


80 changes: 80 additions & 0 deletions projects/cour_des_comptes/models/marts/users/users.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,80 @@
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.email_on_notification,
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
Original file line number Diff line number Diff line change
@@ -0,0 +1,42 @@
WITH source AS (
SELECT * FROM {{ source('decidim', 'decidim_users') }}
),
renamed AS (
SELECT
id,
email,
sign_in_count,
last_sign_in_at,
created_at,
updated_at,
invitation_created_at,
invitation_sent_at,
invitation_accepted_at,
invited_by_id,
invited_by_type,
decidim_organization_id,
confirmed_at,
confirmation_token,
unconfirmed_email,
name,
locale,
deleted_at,
admin,
managed,
roles::text AS roles,
-- email_on_notification,
nickname,
accepted_tos_version,
type,
following_count,
followers_count,
failed_attempts,
locked_at,
admin_terms_accepted_at,
blocked,
blocked_at,
(CASE WHEN confirmed_at IS NULL THEN false ELSE true END) AS "confirmed",
extended_data
FROM source
)
SELECT * FROM renamed

0 comments on commit 2f06460

Please sign in to comment.