From 84d84764d9748d851e7c6b40438bab85e2e35e67 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Dafydd=20Ll=C5=B7r=20Pearson?= Date: Thu, 16 May 2024 16:18:56 +0100 Subject: [PATCH] feat: Capture `node_data` directly alongside feeback (#3156) --- editor.planx.uk/src/lib/feedback.ts | 5 ++ hasura.planx.uk/metadata/tables.yaml | 1 + .../down.sql | 3 + .../up.sql | 4 ++ .../1715868696352_run_sql_migration/down.sql | 54 ++++++++++++++ .../1715868696352_run_sql_migration/up.sql | 40 +++++++++++ scripts/seed-database/container.sh | 14 +++- scripts/seed-database/write/feedback.sql | 70 +++++++++++++++++++ scripts/seed-database/write/main.sql | 6 +- 9 files changed, 195 insertions(+), 2 deletions(-) create mode 100644 hasura.planx.uk/migrations/1715867685564_alter_table_public_feedback_add_column_node_data/down.sql create mode 100644 hasura.planx.uk/migrations/1715867685564_alter_table_public_feedback_add_column_node_data/up.sql create mode 100644 hasura.planx.uk/migrations/1715868696352_run_sql_migration/down.sql create mode 100644 hasura.planx.uk/migrations/1715868696352_run_sql_migration/up.sql create mode 100644 scripts/seed-database/write/feedback.sql diff --git a/editor.planx.uk/src/lib/feedback.ts b/editor.planx.uk/src/lib/feedback.ts index 5cef2cd2b3..f3b8b3f7a0 100644 --- a/editor.planx.uk/src/lib/feedback.ts +++ b/editor.planx.uk/src/lib/feedback.ts @@ -17,6 +17,7 @@ export type FeedbackMetadata = { nodeType?: string | null; device: Bowser.Parser.ParsedResult; userData: UserData; + nodeData: Store.node["data"]; }; export async function getInternalFeedbackMetadata(): Promise { @@ -40,6 +41,7 @@ export async function getInternalFeedbackMetadata(): Promise { nodeType: node?.type ? TYPES[node.type] : null, device: Bowser.parse(window.navigator.userAgent), userData: userData, + nodeData: node?.data }; return metadata; @@ -55,6 +57,7 @@ export async function insertFeedbackMutation(data: { userContext?: string; userComment: string; feedbackType: string; + nodeData?: Store.node["data"]; }) { const result = await publicClient.mutate({ mutation: gql` @@ -68,6 +71,7 @@ export async function insertFeedbackMutation(data: { $userContext: String $userComment: String! $feedbackType: feedback_type_enum_enum! + $nodeData: jsonb ) { insert_feedback( objects: { @@ -80,6 +84,7 @@ export async function insertFeedbackMutation(data: { user_context: $userContext user_comment: $userComment feedback_type: $feedbackType + node_data: $nodeData } ) { affected_rows diff --git a/hasura.planx.uk/metadata/tables.yaml b/hasura.planx.uk/metadata/tables.yaml index 1227515ef1..d4ac73921d 100644 --- a/hasura.planx.uk/metadata/tables.yaml +++ b/hasura.planx.uk/metadata/tables.yaml @@ -239,6 +239,7 @@ - feedback_type - flow_id - id + - node_data - node_id - node_type - status diff --git a/hasura.planx.uk/migrations/1715867685564_alter_table_public_feedback_add_column_node_data/down.sql b/hasura.planx.uk/migrations/1715867685564_alter_table_public_feedback_add_column_node_data/down.sql new file mode 100644 index 0000000000..7510aee37e --- /dev/null +++ b/hasura.planx.uk/migrations/1715867685564_alter_table_public_feedback_add_column_node_data/down.sql @@ -0,0 +1,3 @@ +comment on column "public"."feedback"."node_data" is NULL; + +ALTER TABLE feedback DROP COLUMN node_data; diff --git a/hasura.planx.uk/migrations/1715867685564_alter_table_public_feedback_add_column_node_data/up.sql b/hasura.planx.uk/migrations/1715867685564_alter_table_public_feedback_add_column_node_data/up.sql new file mode 100644 index 0000000000..4ba168c52d --- /dev/null +++ b/hasura.planx.uk/migrations/1715867685564_alter_table_public_feedback_add_column_node_data/up.sql @@ -0,0 +1,4 @@ +alter table "public"."feedback" add column "node_data" jsonb + null; + +comment on column "public"."feedback"."node_data" is E'The data of the node the user was on when their feedback was left'; \ No newline at end of file diff --git a/hasura.planx.uk/migrations/1715868696352_run_sql_migration/down.sql b/hasura.planx.uk/migrations/1715868696352_run_sql_migration/down.sql new file mode 100644 index 0000000000..2e4e16b856 --- /dev/null +++ b/hasura.planx.uk/migrations/1715868696352_run_sql_migration/down.sql @@ -0,0 +1,54 @@ +DROP VIEW "public"."feedback_summary"; + +-- Most recent version of view from planx-new/hasura.planx.uk/migrations/1715784133713_run_sql_migration/up.sql +CREATE OR REPLACE VIEW "public"."feedback_summary" AS +SELECT + fb.id AS feedback_id, + t.slug AS team, + f.slug AS service_slug, + fb.created_at, + fb.node_id, + fb.device, + fb.user_context, + fb.user_comment, + fb.feedback_type, + fb.status, + fb.node_type, + COALESCE( + published_flow_node.data ->> 'title', + published_flow_node.data ->> 'text', + published_flow_node.data ->> 'flagSet' + ) AS node_title, + published_flow_node.data ->> 'description' AS node_text, + published_flow_node.data ->> 'info' AS help_text, + published_flow_node.data ->> 'policyRef' AS help_sources, + published_flow_node.data ->> 'howMeasured' AS help_definition, + COALESCE( + fb.user_data -> 'passport' -> 'data' -> '_address' ->> 'single_line_address', + fb.user_data -> 'passport' -> 'data' -> '_address' ->> 'title' + ) AS address, + (fb.user_data -> 'passport' -> 'data' -> '_address' ->> 'uprn') AS uprn, + (fb.user_data -> 'passport' -> 'data' ->> 'proposal.projectType') AS project_type, + (fb.user_data -> 'passport' -> 'data' ->> 'property.constraints.planning') AS intersecting_constraints, + published_flow_node.data AS node_data +FROM + feedback fb +LEFT JOIN + flows f ON f.id = fb.flow_id +LEFT JOIN + teams t ON t.id = fb.team_id +LEFT JOIN LATERAL + ( + SELECT + (published_flows.data -> fb.node_id) -> 'data' AS data + FROM + published_flows + WHERE + published_flows.flow_id = fb.flow_id + AND published_flows.created_at < fb.created_at + ORDER BY + published_flows.created_at DESC + LIMIT 1 + ) AS published_flow_node ON true; + +GRANT SELECT ON public.feedback_summary TO metabase_read_only; diff --git a/hasura.planx.uk/migrations/1715868696352_run_sql_migration/up.sql b/hasura.planx.uk/migrations/1715868696352_run_sql_migration/up.sql new file mode 100644 index 0000000000..acfa8a9478 --- /dev/null +++ b/hasura.planx.uk/migrations/1715868696352_run_sql_migration/up.sql @@ -0,0 +1,40 @@ +DROP VIEW "public"."feedback_summary"; + +CREATE OR REPLACE VIEW "public"."feedback_summary" AS +SELECT + fb.id AS feedback_id, + t.slug AS team, + f.slug AS service_slug, + fb.created_at, + fb.node_id, + fb.device, + fb.user_context, + fb.user_comment, + fb.feedback_type, + fb.status, + fb.node_type, + fb.node_data, + COALESCE( + fb.node_data ->> 'title', + fb.node_data ->> 'text', + fb.node_data ->> 'flagSet' + ) AS node_title, + fb.node_data ->> 'description' AS node_text, + fb.node_data ->> 'info' AS help_text, + fb.node_data ->> 'policyRef' AS help_sources, + fb.node_data ->> 'howMeasured' AS help_definition, + COALESCE( + fb.user_data -> 'passport' -> 'data' -> '_address' ->> 'single_line_address', + fb.user_data -> 'passport' -> 'data' -> '_address' ->> 'title' + ) AS address, + (fb.user_data -> 'passport' -> 'data' -> '_address' ->> 'uprn') AS uprn, + (fb.user_data -> 'passport' -> 'data' ->> 'proposal.projectType') AS project_type, + (fb.user_data -> 'passport' -> 'data' ->> 'property.constraints.planning') AS intersecting_constraints +FROM + feedback fb +LEFT JOIN + flows f ON f.id = fb.flow_id +LEFT JOIN + teams t ON t.id = fb.team_id; + +GRANT SELECT ON public.feedback_summary TO metabase_read_only; diff --git a/scripts/seed-database/container.sh b/scripts/seed-database/container.sh index c3647b268c..6ba5556ba8 100755 --- a/scripts/seed-database/container.sh +++ b/scripts/seed-database/container.sh @@ -18,7 +18,19 @@ mkdir -p /tmp # Create sync.sql file for all our comnands which will be executed in a single transaction touch '/tmp/sync.sql' -tables=(flows users teams flow_document_templates team_members team_themes) +tables=( + # Mandatory tables + flows + users + teams + flow_document_templates + team_members + team_themes + # Optional tables + # Please comment in if working on a feature and you require example data locally + # You will need to manually grant select permissions to the github_actions on production, and update main.sql + feedback +) # run copy commands on remote db for table in "${tables[@]}"; do diff --git a/scripts/seed-database/write/feedback.sql b/scripts/seed-database/write/feedback.sql new file mode 100644 index 0000000000..833bf886f8 --- /dev/null +++ b/scripts/seed-database/write/feedback.sql @@ -0,0 +1,70 @@ +-- insert feedback overwriting conflicts +CREATE TEMPORARY TABLE sync_feedback ( + id integer, + team_id integer, + flow_id uuid, + created_at timestamptz, + node_id text, + device jsonb, + user_data jsonb, + user_context text, + user_comment text, + feedback_type text, + status text, + node_type text, + node_data jsonb +); + +\copy sync_feedback FROM '/tmp/feedback.csv' WITH (FORMAT csv, DELIMITER ';'); + +INSERT INTO + feedback ( + id, + team_id, + flow_id, + created_at, + node_id, + device, + user_data, + user_context, + user_comment, + feedback_type, + status, + node_type, + node_data + ) +SELECT + id, + team_id, + flow_id, + created_at, + node_id, + device, + user_data, + user_context, + user_comment, + feedback_type, + status, + node_type, + node_data +FROM + sync_feedback ON CONFLICT (id) DO +UPDATE +SET + id = EXCLUDED.id, + team_id = EXCLUDED.team_id, + flow_id = EXCLUDED.flow_id, + created_at = EXCLUDED.created_at, + node_id = EXCLUDED.node_id, + device = EXCLUDED.device, + user_data = EXCLUDED.user_data, + user_context = EXCLUDED.user_context, + user_comment = EXCLUDED.user_comment, + feedback_type = EXCLUDED.feedback_type, + status = EXCLUDED.status, + node_type = EXCLUDED.node_type, + node_data = EXCLUDED.node_data; +SELECT + setval('feedback_id_seq', max(id)) +FROM + feedback; \ No newline at end of file diff --git a/scripts/seed-database/write/main.sql b/scripts/seed-database/write/main.sql index 5ae353a990..c5db62ae96 100644 --- a/scripts/seed-database/write/main.sql +++ b/scripts/seed-database/write/main.sql @@ -1,3 +1,4 @@ +-- Mandatory tables \include write/users.sql \include write/teams.sql \include write/flows.sql @@ -5,4 +6,7 @@ \include write/published_flows.sql \include write/team_members.sql \include write/team_integrations.sql -\include write/team_themes.sql \ No newline at end of file +\include write/team_themes.sql + +-- Optional tables +\include write/feedback.sql \ No newline at end of file