Skip to content

Commit

Permalink
Merge pull request #42 from OpenSourcePolitics/fix_cdc_age_unit_test
Browse files Browse the repository at this point in the history
fix(cdc): use dbt_date to variabilize age calculation unit test
  • Loading branch information
JeanLouisLamezec authored Dec 9, 2024
2 parents 5a80c10 + 0139345 commit eeecb14
Show file tree
Hide file tree
Showing 6 changed files with 135 additions and 52 deletions.
6 changes: 4 additions & 2 deletions projects/cour_des_comptes/dbt_project.yml
Original file line number Diff line number Diff line change
Expand Up @@ -22,6 +22,9 @@ clean-targets: # directories to be removed by `dbt clean`
- "target"
- "dbt_packages"

vars:
"dbt_date:time_zone": "Europe/Paris"

# Configuring models
# Full documentation: https://docs.getdbt.com/docs/configuring-models

Expand All @@ -36,8 +39,7 @@ models:
+enabled: false
marts:
users:
users:
+enabled: false
+enabled: false

cour_des_comptes:
+materialized: table
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -90,7 +90,7 @@ FROM users_with_date_of_birth
users_with_age AS (
SELECT
*,
EXTRACT(YEAR FROM AGE(CURRENT_DATE, DATE(users_with_correct_age.date_of_birth))) AS age
EXTRACT(YEAR FROM AGE({{ dbt_date.today() }}, DATE(users_with_correct_age.date_of_birth))) AS age
FROM users_with_correct_age
)

Expand Down
17 changes: 10 additions & 7 deletions projects/cour_des_comptes/models/intermediate/users/schema.yml
Original file line number Diff line number Diff line change
Expand Up @@ -7,19 +7,22 @@ unit_tests:
- 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: 1, extended_data: '{"date_of_birth": "1943-11-06"}', type: 'Decidim::User'}
- {id: 2, extended_data: '{"date_of_birth": "1958-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: 4, extended_data: '{"date_of_birth": "1992-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: 69, 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: 1, date_of_birth: "1943-11-06", age: 66, age_category: "[65-69 ans]"}
- {id: 2, date_of_birth: "1958-06-23", age: 51, age_category: "[50-54 ans]"}
- {id: 3, date_of_birth: "1932-05-23", age: 77, age_category: "[75 ans ou plus]"}
- {id: 4, date_of_birth: "1992-12-01", age: 17, age_category: "[15-19 ans]"}
- {id: 5, date_of_birth: null, age: null, age_category: 'Âge non défini'}
overrides:
macros:
dbt_date.today: "'2010-01-01'"

- name: testing_date_out_of_range
description: "Checks that age is undefined if field value out of range"
Expand Down
112 changes: 112 additions & 0 deletions projects/cour_des_comptes/models/marts/users/all_users.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,112 @@
WITH endorsements AS (
SELECT
decidim_author_id,
MAX(1) AS is_endorsing
FROM {{ ref("endorsements") }}
GROUP BY decidim_author_id
),

comments AS (
SELECT
decidim_author_id,
MAX(1) AS has_authored_comment
FROM {{ ref("comments") }}
GROUP BY decidim_author_id
),

forms_answers AS (
SELECT
decidim_user_id,
MAX(1) AS has_answered_survey
FROM {{ ref("forms_answers") }}
GROUP BY decidim_user_id
),

proposal_votes AS (
SELECT
decidim_author_id,
MAX(1) AS has_voted_on_proposal
FROM {{ ref("proposals_votes") }}
GROUP BY decidim_author_id
),

project_votes AS (
SELECT
decidim_user_id,
MAX(1) AS has_voted_on_project
FROM {{ ref("projects_votes") }}
GROUP BY decidim_user_id
),

participations_proposals AS (
SELECT
decidim_coauthorships.decidim_author_id,
MAX(1) AS has_authored_proposal
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'
GROUP BY decidim_coauthorships.decidim_author_id
),

followings AS (
SELECT DISTINCT decidim_user_id
FROM {{ ref("followings") }}
)

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(endorsements.is_endorsing, 0)::boolean AS is_endorsing,
(CASE WHEN followings.decidim_user_id IS NULL THEN false ELSE true END) AS is_following,
COALESCE(comments.has_authored_comment, 0)::boolean AS has_authored_comment,
COALESCE(proposal_votes.has_voted_on_proposal, 0)::boolean AS has_voted_on_proposal,
COALESCE(project_votes.has_voted_on_project, 0)::boolean AS has_voted_on_project,
COALESCE(participations_proposals.has_authored_proposal, 0)::boolean AS has_authored_proposal,
COALESCE(forms_answers.has_answered_survey, 0)::boolean AS 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 endorsements ON endorsements.decidim_author_id = decidim_users.id
LEFT JOIN comments ON comments.decidim_author_id = decidim_users.id
LEFT JOIN forms_answers ON forms_answers.decidim_user_id = decidim_users.id
LEFT JOIN proposal_votes ON proposal_votes.decidim_author_id = decidim_users.id
LEFT JOIN project_votes ON project_votes.decidim_user_id = decidim_users.id
LEFT JOIN participations_proposals ON participations_proposals.decidim_author_id = decidim_users.id
JOIN {{ ref("int_organizations") }} AS decidim_organizations
ON decidim_organizations.id = decidim_users.decidim_organization_id
46 changes: 5 additions & 41 deletions projects/cour_des_comptes/models/marts/users/users.sql
Original file line number Diff line number Diff line change
@@ -1,31 +1,3 @@
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,
Expand Down Expand Up @@ -59,21 +31,13 @@ SELECT
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
FROM {{ ref('all_users') }} AS decidim_users
WHERE deleted_at IS NULL
AND decidim_users.blocked != true
AND decidim_users.admin != true
AND decidim_users.confirmed = true
4 changes: 3 additions & 1 deletion projects/cour_des_comptes/packages.yml
Original file line number Diff line number Diff line change
@@ -1,4 +1,6 @@
packages:
- local: ../demo
- package: dbt-labs/dbt_utils
version: 1.2.0
version: 1.2.0
- package: calogica/dbt_date
version: 0.10.1

0 comments on commit eeecb14

Please sign in to comment.