-
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: Unwrap JSONB columns in analytics_summary
- Loading branch information
1 parent
18e2116
commit 18b8332
Showing
3 changed files
with
105 additions
and
3 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
42 changes: 42 additions & 0 deletions
42
...a.planx.uk/migrations/1708016067772_alter_view_analytics_summary_unfold_metadata/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,42 @@ | ||
DROP VIEW public.analytics_summary; | ||
|
||
-- Previous version from migration 1702916788570_alter_column_analytics_logs_node_type/up.sql | ||
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, | ||
referrer, | ||
flow_direction, | ||
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 | ||
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; |
49 changes: 49 additions & 0 deletions
49
hasura.planx.uk/migrations/1708016067772_alter_view_analytics_summary_unfold_metadata/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,49 @@ | ||
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, | ||
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 | ||
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; |