Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

feat: split submission_services_summary allow_list_answers into their own columns in view #2927

Merged
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -4,8 +4,13 @@ import { Passport } from "@opensystemslab/planx-core";
import { $api } from "../../../../client";
import { Operation } from "../sanitiseApplicationData/types";

// ALLOW_LIST should stay in sync with
// editor.planx.uk/src/pages/FlowEditor/lib/analyticsProvider
/**
* ALLOW_LIST should stay in sync with
* editor.planx.uk/src/pages/FlowEditor/lib/analyticsProvider
* If appending to ALLOW_LIST please also update the
* `submission_services_summary` view to extract it into it's own column.
*/

const ALLOW_LIST = [
"proposal.projectType",
"application.declaration.connection",
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,121 @@
-- Previous instance of view from hasura.planx.uk/migrations/1710431558909_alter_view_public_submission_services_summary_reinstate_allow_list_answers/up.sql

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,
'submittedAt', created_at,
'destinationUrl', 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,
'submittedAt', 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,
'submittedAt', 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,
'createdAt', created_at,
'paidAt', paid_at,
'govpayPaymentId', 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(
'govpayPaymentId', payment_id,
'createdAt', 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,
ls.allow_list_answers,
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;

-- After recreating the view grant Metabase access to it
GRANT SELECT ON public.submission_services_summary TO metabase_read_only;
Original file line number Diff line number Diff line change
@@ -0,0 +1,125 @@
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,
'submittedAt', created_at,
'destinationUrl', 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,
'submittedAt', 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,
'submittedAt', 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,
'createdAt', created_at,
'paidAt', paid_at,
'govpayPaymentId', 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(
'govpayPaymentId', payment_id,
'createdAt', 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,
ls.allow_list_answers,
Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

ls.allow_list_answers -> 'proposal.projectType' as proposal_project_type,
ls.allow_list_answers -> 'application.declaration.connection' as application_declaration_connection,
ls.allow_list_answers -> 'property.type' as property_type,
ls.allow_list_answers -> 'drawBoundary.action' as draw_boundary_action,
ls.allow_list_answers -> 'user.role' as user_role,
ls.allow_list_answers -> 'property.constraints.planning' as property_constraints_planning,
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;

-- After recreating the view grant Metabase access to it
GRANT SELECT ON public.submission_services_summary TO metabase_read_only;
Loading