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

fix: analytics_logs.node_type should reference text component type rather than integer for new and historic records #2578

Merged
merged 4 commits into from
Dec 19, 2023
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 @@ -154,13 +154,15 @@ export const AnalyticsProvider: React.FC<{ children: React.ReactNode }> = ({
const nodeToTrack = flow[nodeId];

const metadata = getNodeMetadata(nodeToTrack);
const nodeType = nodeToTrack?.type ? TYPES[nodeToTrack.type] : null;
const nodeTitle = extractNodeTitle(nodeToTrack);

// On component transition create the new analytics log
const result = await insertNewAnalyticsLog(
direction,
analyticsId,
metadata,
nodeType,
nodeTitle,
nodeId,
);
Expand All @@ -181,6 +183,7 @@ export const AnalyticsProvider: React.FC<{ children: React.ReactNode }> = ({
direction: AnalyticsLogDirection,
analyticsId: number,
metadata: NodeMetadata,
nodeType: string | null,
nodeTitle: string,
nodeId: string | null,
) {
Expand All @@ -190,7 +193,7 @@ export const AnalyticsProvider: React.FC<{ children: React.ReactNode }> = ({
$flow_direction: String
$analytics_id: bigint
$metadata: jsonb
$node_type: Int
$node_type: String
$node_title: String
$node_id: String
) {
Expand All @@ -214,7 +217,7 @@ export const AnalyticsProvider: React.FC<{ children: React.ReactNode }> = ({
flow_direction: direction,
analytics_id: analyticsId,
metadata: metadata,
node_type: node?.type,
node_type: nodeType,
node_title: nodeTitle,
node_id: nodeId,
},
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,66 @@
DROP VIEW public.analytics_summary;

ALTER TABLE public.analytics_logs
ALTER COLUMN node_type TYPE INTEGER
USING node_type::integer;

UPDATE public.analytics_logs SET node_type =
CASE
WHEN node_type = 'Flow' THEN 1
WHEN node_type = 'Result' THEN 3
WHEN node_type = 'TaskList' THEN 7
WHEN node_type = 'Notice' THEN 8
WHEN node_type = 'FindProperty' THEN 9
WHEN node_type = 'DrawBoundary' THEN 10
WHEN node_type = 'PlanningConstraints' THEN 11
WHEN node_type = 'PropertyInformation' THEN 12
WHEN node_type = 'Statement' THEN 100
WHEN node_type = 'Checklist' THEN 105
WHEN node_type = 'TextInput' THEN 110
WHEN node_type = 'DateInput' THEN 120
WHEN node_type = 'AddressInput' THEN 130
WHEN node_type = 'ContactInput' THEN 135
WHEN node_type = 'FileUpload' THEN 140
WHEN node_type = 'FileUploadAndLabel' THEN 145
WHEN node_type = 'NumberInput' THEN 150
WHEN node_type = 'Response' THEN 200
WHEN node_type = 'Content' THEN 250
WHEN node_type = 'InternalPortal' THEN 300
WHEN node_type = 'ExternalPortal' THEN 310
WHEN node_type = 'Section' THEN 360
WHEN node_type = 'SetValue' THEN 380
WHEN node_type = 'Pay' THEN 400
WHEN node_type = 'Filter' THEN 500
WHEN node_type = 'Review' THEN 600
WHEN node_type = 'Send' THEN 650
WHEN node_type = 'Calculate' THEN 700
WHEN node_type = 'Confirmation' THEN 725
WHEN node_type = 'NextSteps' THEN 730
ELSE null
END;

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,70 @@
-- ALTER COLUMN will fail if dependent view exists
DROP VIEW public.analytics_summary;

-- Update column type from integer to text
ALTER TABLE public.analytics_logs
ALTER COLUMN node_type TYPE TEXT
USING node_type::text;

-- Do a one-time update of historic records
UPDATE public.analytics_logs SET node_type =
CASE
WHEN node_type = '1' THEN 'Flow'
WHEN node_type = '3' THEN 'Result'
WHEN node_type = '7' THEN 'TaskList'
WHEN node_type = '8' THEN 'Notice'
WHEN node_type = '9' THEN 'FindProperty'
WHEN node_type = '10' THEN 'DrawBoundary'
WHEN node_type = '11' THEN 'PlanningConstraints'
WHEN node_type = '12' THEN 'PropertyInformation'
WHEN node_type = '100' THEN 'Statement'
Copy link
Contributor

Choose a reason for hiding this comment

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

This has always felt like a bit of a tricky one - if we get feedback that this is oddly named we can very easily update to "Question" or something in future 👍

Copy link
Member Author

Choose a reason for hiding this comment

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

Yep agree - that's probably a change we should consider making at the root type definition rather than just analytics! Hopefully ambiguous text is still a huge upgrade from integer for starters though!

WHEN node_type = '105' THEN 'Checklist'
WHEN node_type = '110' THEN 'TextInput'
WHEN node_type = '120' THEN 'DateInput'
WHEN node_type = '130' THEN 'AddressInput'
WHEN node_type = '135' THEN 'ContactInput'
WHEN node_type = '140' THEN 'FileUpload'
WHEN node_type = '145' THEN 'FileUploadAndLabel'
WHEN node_type = '150' THEN 'NumberInput'
WHEN node_type = '200' THEN 'Response'
WHEN node_type = '250' THEN 'Content'
WHEN node_type = '300' THEN 'InternalPortal'
WHEN node_type = '310' THEN 'ExternalPortal'
WHEN node_type = '360' THEN 'Section'
WHEN node_type = '380' THEN 'SetValue'
WHEN node_type = '400' THEN 'Pay'
WHEN node_type = '500' THEN 'Filter'
WHEN node_type = '600' THEN 'Review'
WHEN node_type = '650' THEN 'Send'
WHEN node_type = '700' THEN 'Calculate'
WHEN node_type = '725' THEN 'Confirmation'
WHEN node_type = '730' THEN 'NextSteps'
ELSE null
END;

-- Re-create the view
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;
Loading