-
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.
chore: update existing analytics_logs allow_list_answers to be an object
- Convert from an array of objects to a single object - Currently we have no records in prod where the [allow_list_answers is longer than 1](https://metabase.editor.planx.uk/question/354-number-of-analytics-logs-with-allow-list-answers-greater-than-1) so we can use this to convert - Update the `analytics_summary` db view to handle the change to the data structure
- Loading branch information
1 parent
98e59e7
commit 48cb555
Showing
2 changed files
with
146 additions
and
0 deletions.
There are no files selected for viewing
72 changes: 72 additions & 0 deletions
72
...igrations/1711643574155_update_analytics_logs_allow_list_answers_array_to_object/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,72 @@ | ||
-- Update the data structure of allow_list_answers to revert it to an array of objects | ||
|
||
UPDATE public.analytics_logs | ||
SET allow_list_answers = jsonb_build_array(allow_list_answers) | ||
WHERE jsonb_typeof(allow_list_answers) != 'array'; | ||
|
||
-- Previous instance of view from hasura.planx.uk/migrations/1711457331702_alter_view_public_analytics_summary_split_allow_list_answers_into_columns/up.sql | ||
DROP VIEW public.analytics_summary; | ||
|
||
CREATE | ||
OR REPLACE VIEW public.analytics_summary AS | ||
select | ||
a.id as analytics_id, | ||
al.id as analytics_log_id, | ||
f.slug as service_slug, | ||
t.slug as team_slug, | ||
a.type as analytics_type, | ||
al.created_at as analytics_log_created_at, | ||
a.created_at as analytics_created_at, | ||
(user_agent -> 'os' ->> 'name') :: text AS operating_system, | ||
(user_agent -> 'browser' ->> 'name') :: text AS browser, | ||
(user_agent -> 'platform' ->> 'type') :: text AS platform, | ||
referrer, | ||
flow_direction, | ||
metadata ->> 'change' as change_metadata, | ||
metadata ->> 'back' as back_metadata, | ||
metadata ->> 'selectedUrls' as selected_urls, | ||
metadata ->> 'flag' as result_flag, | ||
metadata -> 'flagSet' as result_flagset, | ||
metadata -> 'displayText' ->> 'heading' as result_heading, | ||
metadata -> 'displayText' ->> 'description' as result_description, | ||
case | ||
when has_clicked_help then metadata | ||
else null | ||
end as help_metadata, | ||
al.user_exit as is_user_exit, | ||
node_type, | ||
node_title, | ||
has_clicked_help, | ||
input_errors, | ||
CAST( | ||
EXTRACT( | ||
EPOCH | ||
FROM | ||
(al.next_log_created_at - al.created_at) | ||
) as numeric (10, 1) | ||
) as time_spent_on_node_seconds, | ||
a.ended_at as analytics_ended_at, | ||
CAST( | ||
EXTRACT( | ||
EPOCH | ||
FROM | ||
(a.ended_at - a.created_at) | ||
) / 60 as numeric (10, 1) | ||
) as time_spent_on_analytics_session_minutes, | ||
node_id, | ||
al.allow_list_answers as allow_list_answers, | ||
allow_list_answer_elements->>'proposal.projectType' AS proposal_project_type, | ||
allow_list_answer_elements->>'application.declaration.connection' AS application_declaration_connection, | ||
allow_list_answer_elements->>'property.type' AS property_type, | ||
allow_list_answer_elements->>'drawBoundary.action' AS draw_boundary_action, | ||
allow_list_answer_elements->>'user.role' AS user_role, | ||
allow_list_answer_elements->>'property.constraints.planning' AS property_constraints_planning | ||
from | ||
analytics a | ||
left join analytics_logs al on a.id = al.analytics_id | ||
left join flows f on a.flow_id = f.id | ||
left join teams t on t.id = f.team_id | ||
left join lateral jsonb_array_elements(al.allow_list_answers) AS allow_list_answer_elements ON true; | ||
|
||
-- After recreating the view grant Metabase access to it | ||
GRANT SELECT ON public.analytics_summary TO metabase_read_only; |
74 changes: 74 additions & 0 deletions
74
.../migrations/1711643574155_update_analytics_logs_allow_list_answers_array_to_object/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,74 @@ | ||
-- Update the data structure of allow_list_answers to be an object rather than array of objects | ||
|
||
UPDATE public.analytics_logs | ||
SET allow_list_answers = allow_list_answers->0 | ||
WHERE jsonb_typeof(allow_list_answers) = 'array' AND jsonb_array_length(allow_list_answers) = 1; | ||
|
||
-- Update the analytics_summary to handle the change to the data structure | ||
|
||
DROP VIEW public.analytics_summary; | ||
|
||
CREATE | ||
OR REPLACE VIEW public.analytics_summary AS | ||
select | ||
a.id as analytics_id, | ||
al.id as analytics_log_id, | ||
f.slug as service_slug, | ||
t.slug as team_slug, | ||
a.type as analytics_type, | ||
al.created_at as analytics_log_created_at, | ||
a.created_at as analytics_created_at, | ||
(user_agent -> 'os' ->> 'name') :: text AS operating_system, | ||
(user_agent -> 'browser' ->> 'name') :: text AS browser, | ||
(user_agent -> 'platform' ->> 'type') :: text AS platform, | ||
referrer, | ||
flow_direction, | ||
metadata ->> 'change' as change_metadata, | ||
metadata ->> 'back' as back_metadata, | ||
metadata ->> 'selectedUrls' as selected_urls, | ||
metadata ->> 'flag' as result_flag, | ||
metadata -> 'flagSet' as result_flagset, | ||
metadata -> 'displayText' ->> 'heading' as result_heading, | ||
metadata -> 'displayText' ->> 'description' as result_description, | ||
case | ||
when has_clicked_help then metadata | ||
else null | ||
end as help_metadata, | ||
al.user_exit as is_user_exit, | ||
node_type, | ||
node_title, | ||
has_clicked_help, | ||
input_errors, | ||
CAST( | ||
EXTRACT( | ||
EPOCH | ||
FROM | ||
(al.next_log_created_at - al.created_at) | ||
) as numeric (10, 1) | ||
) as time_spent_on_node_seconds, | ||
a.ended_at as analytics_ended_at, | ||
CAST( | ||
EXTRACT( | ||
EPOCH | ||
FROM | ||
(a.ended_at - a.created_at) | ||
) / 60 as numeric (10, 1) | ||
) as time_spent_on_analytics_session_minutes, | ||
node_id, | ||
al.allow_list_answers as allow_list_answers, | ||
al.allow_list_answers -> 'proposal.projectType' as proposal_project_type, | ||
al.allow_list_answers -> 'application.declaration.connection' as application_declaration_connection, | ||
al.allow_list_answers -> 'property.type' as property_type, | ||
al.allow_list_answers -> 'drawBoundary.action' as draw_boundary_action, | ||
al.allow_list_answers -> 'user.role' as user_role, | ||
al.allow_list_answers -> 'property.constraints.planning' as property_constraints_planning | ||
from | ||
analytics a | ||
left join analytics_logs al on a.id = al.analytics_id | ||
left join flows f on a.flow_id = f.id | ||
left join teams t on t.id = f.team_id; | ||
|
||
-- After recreating the view grant Metabase access to it | ||
GRANT SELECT ON public.analytics_summary TO metabase_read_only; | ||
|
||
|