-
Notifications
You must be signed in to change notification settings - Fork 2
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
feat: expand the application data exposed on submission_services_summ…
…ary (#2879)
- Loading branch information
1 parent
644884e
commit 666385f
Showing
3 changed files
with
213 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
50 changes: 50 additions & 0 deletions
50
...ons/1710258204814_alter_view_submission_services_summary_expand_application_data/down.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,50 @@ | ||
drop view public.submission_services_summary; | ||
|
||
-- Previous instance of view from hasura.planx.uk/migrations/1700072112794_create_view_submission_services_summary/up.sql | ||
CREATE OR REPLACE VIEW public.submission_services_summary AS | ||
with resumes_per_session as ( | ||
select | ||
session_id, | ||
count(id) as number_times_resumed | ||
from reconciliation_requests | ||
group by session_id | ||
) | ||
select | ||
ls.id as session_id, | ||
t.slug as team_slug, | ||
f.slug as service_slug, | ||
ls.created_at, | ||
ls.submitted_at, | ||
(ls.submitted_at::date - ls.created_at::date) as session_length_days, | ||
ls.has_user_saved as user_clicked_save, | ||
rps.number_times_resumed, | ||
case | ||
when pr.id is null | ||
then false | ||
else true | ||
end as user_invited_to_pay, | ||
case | ||
when ba.bops_id is null | ||
then false | ||
else true | ||
end as sent_to_bops, | ||
case | ||
when ua.idox_submission_id is null | ||
then false | ||
else true | ||
end as sent_to_uniform, | ||
case | ||
when ea.id is null | ||
then false | ||
else true | ||
end as sent_to_email | ||
from lowcal_sessions ls | ||
left join flows f on f.id = ls.flow_id | ||
left join teams t on t.id = f.team_id | ||
left join resumes_per_session rps on rps.session_id = ls.id::text | ||
left join payment_requests pr on pr.session_id = ls.id | ||
left join bops_applications ba on ba.session_id = ls.id::text | ||
left join uniform_applications ua on ua.submission_reference = ls.id::text | ||
left join email_applications ea on ea.session_id = ls.id | ||
where f.slug IS NOT NULL | ||
and t.slug IS NOT NULL; |
115 changes: 115 additions & 0 deletions
115
...tions/1710258204814_alter_view_submission_services_summary_expand_application_data/up.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,115 @@ | ||
drop view "public"."submission_services_summary"; | ||
|
||
create or replace view "public"."submission_services_summary" as | ||
with resumes_per_session as ( | ||
select | ||
session_id, | ||
count(id) as number_times_resumed | ||
from reconciliation_requests | ||
group by session_id | ||
), bops_agg as ( | ||
select | ||
session_id, | ||
json_agg( | ||
json_build_object( | ||
'id', bops_id, | ||
'submitted_at', created_at, | ||
'destination_url', destination_url | ||
) order by created_at desc | ||
) as bops_applications | ||
from bops_applications | ||
group by session_id | ||
), email_agg as ( | ||
select | ||
session_id, | ||
json_agg( | ||
json_build_object( | ||
'id', id, | ||
'recipient', recipient, | ||
'submitted_at', created_at | ||
) order by created_at desc | ||
) as email_applications | ||
from email_applications | ||
group by session_id | ||
), uniform_agg as ( | ||
select | ||
submission_reference, | ||
json_agg( | ||
json_build_object( | ||
'id', idox_submission_id, | ||
'submitted_at', created_at | ||
) order by created_at desc | ||
) as uniform_applications | ||
from uniform_applications | ||
group by submission_reference | ||
), payment_requests_agg as ( | ||
select | ||
session_id, | ||
json_agg( | ||
json_build_object( | ||
'id', id, | ||
'created_at', created_at, | ||
'paid_at', paid_at, | ||
'govpay_payment_id', govpay_payment_id | ||
) order by created_at desc | ||
) as payment_requests | ||
from payment_requests | ||
group by session_id | ||
), payment_status_agg as ( | ||
select | ||
session_id, | ||
json_agg( | ||
json_build_object( | ||
'govpay_payment_id', payment_id, | ||
'created_at', created_at, | ||
'status', status | ||
) order by created_at desc | ||
) as payment_status | ||
from payment_status | ||
group by session_id | ||
) | ||
select | ||
ls.id::text as session_id, | ||
t.slug as team_slug, | ||
f.slug as service_slug, | ||
ls.created_at, | ||
ls.submitted_at, | ||
(ls.submitted_at::date - ls.created_at::date) as session_length_days, | ||
ls.has_user_saved as user_clicked_save, | ||
rps.number_times_resumed, | ||
case | ||
when pr.payment_requests::jsonb is not null and jsonb_array_length(pr.payment_requests::jsonb) > 0 | ||
then true | ||
else false | ||
end as user_invited_to_pay, | ||
pr.payment_requests, | ||
ps.payment_status, | ||
case | ||
when ba.bops_applications::jsonb is not null and jsonb_array_length(ba.bops_applications::jsonb) > 0 | ||
then true | ||
else false | ||
end as sent_to_bops, | ||
ba.bops_applications, | ||
case | ||
when ua.uniform_applications::jsonb is not null and jsonb_array_length(ua.uniform_applications::jsonb) > 0 | ||
then true | ||
else false | ||
end as sent_to_uniform, | ||
ua.uniform_applications, | ||
case | ||
when ea.email_applications::jsonb is not null and jsonb_array_length(ea.email_applications::jsonb) > 0 | ||
then true | ||
else false | ||
end as sent_to_email, | ||
ea.email_applications | ||
from lowcal_sessions ls | ||
left join flows f on f.id = ls.flow_id | ||
left join teams t on t.id = f.team_id | ||
left join resumes_per_session rps on rps.session_id = ls.id::text | ||
left join payment_requests_agg pr on pr.session_id = ls.id | ||
left join payment_status_agg ps on ps.session_id = ls.id | ||
left join bops_agg ba on ba.session_id = ls.id::text | ||
left join uniform_agg ua on ua.submission_reference = ls.id::text | ||
left join email_agg ea on ea.session_id = ls.id | ||
where f.slug is not null | ||
and t.slug is not null; |