-
Notifications
You must be signed in to change notification settings - Fork 2
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 allow_list_answers column in analytics_summary view #2926
Changes from all commits
File filter
Filter by extension
Conversations
Jump to
Diff view
Diff view
There are no files selected for viewing
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,58 @@ | ||
-- Previous instance of view from hasura.planx.uk/migrations/1709208323190_run_sql_migration/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, | ||
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 | ||
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; |
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,65 @@ | ||
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, | ||
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. I'm not sure we need to keep the current column - what do you think? There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. I don't think it adds much value beyond being a reference to check that data is being extracted properly etc. I'm tempted to remove it 👀 There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. Counter to my previous point I think it could also be handy to check whether a new value in There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. Yep this is a good enough reason for me to keep it - it can just not be used in Metabase directly 👍 |
||
allow_list_answer_elements->>'proposal.projectType' AS proposal_project_type, | ||
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. I was a little unsure about the format of the new column names. I went for There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. I think keeping these as |
||
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; | ||
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. Nice 👌 |
||
|
||
-- After recreating the view grant Metabase access to it | ||
GRANT SELECT ON public.analytics_summary TO metabase_read_only; |
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Perfect - I had this exact comment in mind also!