Skip to content

Commit

Permalink
chore: Unwrap JSONB columns in analytics_summary
Browse files Browse the repository at this point in the history
  • Loading branch information
DafyddLlyr authored and Mike-Heneghan committed Feb 21, 2024
1 parent 18e2116 commit 18b8332
Show file tree
Hide file tree
Showing 3 changed files with 105 additions and 3 deletions.
17 changes: 14 additions & 3 deletions editor.planx.uk/src/pages/FlowEditor/lib/analyticsProvider.tsx
Original file line number Diff line number Diff line change
Expand Up @@ -44,6 +44,15 @@ type NodeMetadata = {
isAutoAnswered?: boolean;
};

/**
* Describes the value held in analytics_logs.metadata
*/
type Metadata =
| Record<"change", NodeMetadata>
| Record<"back", NodeMetadata>
| SelectedUrlsMetadata
| HelpClickMetadata;

let lastVisibleNodeAnalyticsLogId: number | undefined = undefined;

const analyticsContext = createContext<{
Expand Down Expand Up @@ -368,12 +377,14 @@ export const AnalyticsProvider: React.FC<{ children: React.ReactNode }> = ({
if (shouldSkipTracking()) return;

const targetNodeMetadata = nodeId ? getTargetNodeDataFromFlow(nodeId) : {};
const metadata: Record<string, NodeMetadata> = {};
metadata[`${initiator}`] = targetNodeMetadata;
const metadata: Metadata =
initiator === "change"
? { change: targetNodeMetadata }
: { back: targetNodeMetadata };

await publicClient.mutate({
mutation: gql`
mutation UpdateHaInitiatedBackwardsNavigation(
mutation UpdateHasInitiatedBackwardsNavigation(
$id: bigint!
$metadata: jsonb = {}
) {
Expand Down
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;
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;

0 comments on commit 18b8332

Please sign in to comment.