forked from DFE-Digital/early-careers-framework
-
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.
Merge pull request DFE-Digital#2721 from DFE-Digital/update-analytics…
…-queries Rejig the analytics queries for multiple cohorts
- Loading branch information
Showing
4 changed files
with
89 additions
and
40 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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,7 +1,8 @@ | ||
flatten_queries: | ||
flatten_queries: | ||
mkdir -p /tmp/exports | ||
rm -f /tmp/exports/*.sql | ||
cat declarations.sql | tr --delete '\n' > /tmp/exports/declarations.sql | ||
cat participants.sql | tr --delete '\n' > /tmp/exports/participants.sql | ||
cat partnerships.sql | tr --delete '\n' > /tmp/exports/partnerships.sql | ||
cat schools.sql | tr --delete '\n' > /tmp/exports/schools.sql | ||
cat declarations.sql | tr --delete '\n' > /tmp/exports/declarations.sql | ||
cat participants.sql | tr --delete '\n' > /tmp/exports/participants.sql | ||
cat induction_tutors.sql | tr --delete '\n' > /tmp/exports/induction_tutors.sql | ||
cat partnerships.sql | tr --delete '\n' > /tmp/exports/partnerships.sql | ||
cat schools.sql | tr --delete '\n' > /tmp/exports/schools.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,22 @@ | ||
\copy ( | ||
SELECT s.urn, | ||
(icp.id IS NOT NULL) AS tutor_nominated, | ||
icp.created_at AS tutor_nominated_at, | ||
(u.current_sign_in_at IS NOT NULL) AS tutor_signed_in, | ||
u.full_name AS tutor_name, | ||
u.email AS tutor_email, | ||
(pp.id IS NOT NULL) AS sit_mentor, | ||
pi.external_identifier AS sit_mentor_id | ||
|
||
FROM schools s | ||
|
||
LEFT OUTER JOIN induction_coordinator_profiles_schools icps on s.id = icps.school_id | ||
LEFT OUTER JOIN induction_coordinator_profiles icp on icps.induction_coordinator_profile_id = icp.id | ||
LEFT OUTER JOIN users u on icp.user_id = u.id | ||
LEFT OUTER JOIN teacher_profiles tp on u.id = tp.user_id | ||
LEFT OUTER JOIN participant_profiles pp | ||
ON tp.id = pp.teacher_profile_id | ||
AND pp.status = 'active' | ||
AND pp.type = 'ParticipantProfile::Mentor' | ||
LEFT OUTER JOIN participant_identities pi on pp.participant_identity_id = pi.id | ||
) to '/tmp/exports/induction_tutors.csv' with csv header; |
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 |
---|---|---|
@@ -1,12 +1,16 @@ | ||
\copy ( | ||
SELECT s.urn as school_urn, | ||
lp.name as lead_provider_name, | ||
dp.name as delivery_partner_name, | ||
p.created_at AS partnership_reported_at, | ||
p.challenge_reason, | ||
p.challenged_at | ||
FROM partnerships p | ||
JOIN lead_providers lp on lp.id = p.lead_provider_id | ||
JOIN delivery_partners dp on p.delivery_partner_id = dp.id | ||
JOIN schools s on p.school_id = s.id | ||
SELECT s.urn as school_urn, | ||
lp.name as lead_provider_name, | ||
dp.name as delivery_partner_name, | ||
p.created_at as partnership_reported_at, | ||
p.challenge_reason, | ||
p.challenged_at, | ||
c.start_year as cohort, | ||
p.relationship | ||
FROM partnerships p | ||
JOIN lead_providers lp on lp.id = p.lead_provider_id | ||
JOIN delivery_partners dp on p.delivery_partner_id = dp.id | ||
JOIN schools s on p.school_id = s.id | ||
JOIN cohorts c on p.cohort_id = c.id | ||
WHERE NOT p.relationship | ||
) to '/tmp/exports/partnerships.csv' with csv header; |
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 |
---|---|---|
@@ -1,28 +1,50 @@ | ||
\copy ( | ||
SELECT DISTINCT s.urn, | ||
sc.induction_programme_choice, | ||
(p.id IS NOT NULL) as in_partnership, | ||
lp.name as lead_provider_name, | ||
dp.name as delivery_partner_name, | ||
(icp.id IS NOT NULL) as tutor_nominated, | ||
icp.created_at as tutor_nominated_at, | ||
(u.current_sign_in_at IS NOT NULL) as tutor_signed_in, | ||
u.full_name as tutor_name, | ||
u.email as tutor_email, | ||
(pp.id IS NOT NULL) as sit_mentor, | ||
u.id as sit_mentor_id | ||
with everything as ( | ||
select | ||
s.urn, | ||
sc.induction_programme_choice, | ||
(p.id is not null) as in_partnership, | ||
lp.name as lead_provider_name, | ||
dp.name as delivery_partner_name, | ||
c.start_year as cohort | ||
|
||
FROM schools s | ||
LEFT OUTER JOIN school_cohorts sc on s.id = sc.school_id | ||
LEFT OUTER JOIN cohorts c on sc.cohort_id = c.id | ||
LEFT OUTER JOIN partnerships p on s.id = p.school_id | ||
LEFT OUTER JOIN lead_providers lp on p.lead_provider_id = lp.id | ||
LEFT OUTER JOIN delivery_partners dp on p.delivery_partner_id = dp.id | ||
LEFT OUTER JOIN induction_coordinator_profiles_schools icps on s.id = icps.school_id | ||
LEFT OUTER JOIN induction_coordinator_profiles icp on icps.induction_coordinator_profile_id = icp.id | ||
LEFT OUTER JOIN users u on icp.user_id = u.id | ||
LEFT OUTER JOIN teacher_profiles tp on u.id = tp.user_id | ||
LEFT OUTER JOIN participant_profiles pp on tp.id = pp.teacher_profile_id and pp.status = 'active' and | ||
pp.type = 'ParticipantProfile::Mentor' | ||
WHERE (c.start_year > 2020 OR c.id IS NULL) | ||
from schools s | ||
|
||
left outer join school_cohorts sc on s.id = sc.school_id | ||
left outer join cohorts c on sc.cohort_id = c.id | ||
left outer join partnerships p on s.id = p.school_id and c.id = p.cohort_id | ||
left outer join lead_providers lp on p.lead_provider_id = lp.id | ||
left outer join delivery_partners dp on p.delivery_partner_id = dp.id | ||
|
||
where (c.start_year > 2020 or c.id is null) | ||
and p.challenged_at is null | ||
), | ||
just_2021 as ( | ||
select * | ||
from everything | ||
where cohort = 2021 | ||
), | ||
just_2022 as ( | ||
select * | ||
from everything | ||
where cohort = 2022 | ||
) | ||
select | ||
everything.urn, | ||
|
||
just_2021.induction_programme_choice as "2021_induction_programme_choice", | ||
just_2021.in_partnership as "2021_in_partnership", | ||
just_2021.lead_provider_name as "2021_lead_provider_name", | ||
just_2021.delivery_partner_name as "2021_delivery_partner_name", | ||
|
||
just_2022.induction_programme_choice as "2022_induction_programme_choice", | ||
just_2022.in_partnership as "2022_in_partnership", | ||
just_2022.lead_provider_name as "2022_lead_provider_name", | ||
just_2022.delivery_partner_name as "2022_delivery_partner_name" | ||
from | ||
everything | ||
left outer join | ||
just_2021 on everything.urn = just_2021.urn | ||
left outer join | ||
just_2022 on everything.urn = just_2022.urn | ||
) to '/tmp/exports/schools.csv' with csv header; |