Skip to content

Commit

Permalink
fix: ensure Idox Nexus audit entries don't rely on XML generation and…
Browse files Browse the repository at this point in the history
… format submission log event name (#3527)
  • Loading branch information
jessicamcinchak authored Aug 16, 2024
1 parent b0fbc4a commit cdd8ad5
Show file tree
Hide file tree
Showing 3 changed files with 150 additions and 3 deletions.
4 changes: 1 addition & 3 deletions api.planx.uk/modules/send/idox/nexus.ts
Original file line number Diff line number Diff line change
Expand Up @@ -373,8 +373,6 @@ const createUniformApplicationAuditRecord = async ({
localAuthority: string;
submissionDetails: UniformSubmissionResponse;
}): Promise<UniformApplication> => {
const xml = await $api.export.oneAppPayload(payload?.sessionId);

const application: Record<
"insert_uniform_applications_one",
UniformApplication
Expand Down Expand Up @@ -413,7 +411,7 @@ const createUniformApplicationAuditRecord = async ({
destination: localAuthority,
response: submissionDetails,
payload,
xml,
xml: "ODP Schema",
},
);

Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,74 @@
CREATE OR REPLACE VIEW "public"."submission_services_log" AS
WITH payments AS (
SELECT ps.session_id,
ps.payment_id AS event_id,
'Pay'::text AS event_type,
initcap(ps.status) AS status,
jsonb_build_object('status', ps.status, 'description', pse.comment, 'govuk_pay_reference', ps.payment_id) AS response,
ps.created_at,
false AS retry
FROM (payment_status ps
LEFT JOIN payment_status_enum pse ON ((pse.value = ps.status)))
WHERE ((ps.status <> 'created'::text) AND (ps.created_at >= '2024-01-01 00:00:00+00'::timestamp with time zone))
), retries AS (
SELECT hdb_scheduled_event_invocation_logs.id
FROM hdb_catalog.hdb_scheduled_event_invocation_logs
WHERE ((hdb_scheduled_event_invocation_logs.event_id, hdb_scheduled_event_invocation_logs.created_at) IN ( SELECT seil.event_id,
max(seil.created_at) AS max
FROM (hdb_catalog.hdb_scheduled_event_invocation_logs seil
LEFT JOIN hdb_catalog.hdb_scheduled_events se ON ((se.id = seil.event_id)))
WHERE (se.tries > 1)
GROUP BY seil.event_id))
), submissions AS (
SELECT ((((seil.request -> 'payload'::text) -> 'payload'::text) ->> 'sessionId'::text))::uuid AS session_id,
se.id AS event_id,
CASE
WHEN ((se.webhook_conf)::text ~~ '%bops%'::text) THEN 'Submit to BOPS'::text
WHEN ((se.webhook_conf)::text ~~ '%uniform%'::text) THEN 'Submit to Uniform'::text
WHEN ((se.webhook_conf)::text ~~ '%email-submission%'::text) THEN 'Send to email'::text
WHEN ((se.webhook_conf)::text ~~ '%upload-submission%'::text) THEN 'Upload to AWS S3'::text
ELSE (se.webhook_conf)::text
END AS event_type,
CASE
WHEN (seil.status = 200) THEN 'Success'::text
ELSE format('Failed (%s)'::text, seil.status)
END AS status,
(seil.response)::jsonb AS response,
seil.created_at,
(EXISTS ( SELECT 1
FROM retries r
WHERE (r.id = seil.id))) AS retry
FROM (hdb_catalog.hdb_scheduled_events se
LEFT JOIN hdb_catalog.hdb_scheduled_event_invocation_logs seil ON ((seil.event_id = se.id)))
WHERE (((se.webhook_conf)::text !~~ '%email/%'::text) AND (seil.created_at >= '2024-01-01 00:00:00+00'::timestamp with time zone))
), all_events AS (
SELECT payments.session_id,
payments.event_id,
payments.event_type,
payments.status,
payments.response,
payments.created_at,
payments.retry
FROM payments
UNION ALL
SELECT submissions.session_id,
submissions.event_id,
submissions.event_type,
submissions.status,
submissions.response,
submissions.created_at,
submissions.retry
FROM submissions
)
SELECT ls.flow_id,
ae.session_id,
ae.event_id,
ae.event_type,
ae.status,
ae.response,
ae.created_at,
ae.retry
FROM (all_events ae
LEFT JOIN lowcal_sessions ls ON ((ls.id = ae.session_id)))
WHERE (ls.flow_id IS NOT NULL)
ORDER BY ae.created_at DESC;
Original file line number Diff line number Diff line change
@@ -0,0 +1,75 @@
CREATE OR REPLACE VIEW "public"."submission_services_log" AS
WITH payments AS (
SELECT ps.session_id,
ps.payment_id AS event_id,
'Pay'::text AS event_type,
initcap(ps.status) AS status,
jsonb_build_object('status', ps.status, 'description', pse.comment, 'govuk_pay_reference', ps.payment_id) AS response,
ps.created_at,
false AS retry
FROM (payment_status ps
LEFT JOIN payment_status_enum pse ON ((pse.value = ps.status)))
WHERE ((ps.status <> 'created'::text) AND (ps.created_at >= '2024-01-01 00:00:00+00'::timestamp with time zone))
), retries AS (
SELECT hdb_scheduled_event_invocation_logs.id
FROM hdb_catalog.hdb_scheduled_event_invocation_logs
WHERE ((hdb_scheduled_event_invocation_logs.event_id, hdb_scheduled_event_invocation_logs.created_at) IN ( SELECT seil.event_id,
max(seil.created_at) AS max
FROM (hdb_catalog.hdb_scheduled_event_invocation_logs seil
LEFT JOIN hdb_catalog.hdb_scheduled_events se ON ((se.id = seil.event_id)))
WHERE (se.tries > 1)
GROUP BY seil.event_id))
), submissions AS (
SELECT ((((seil.request -> 'payload'::text) -> 'payload'::text) ->> 'sessionId'::text))::uuid AS session_id,
se.id AS event_id,
CASE
WHEN ((se.webhook_conf)::text ~~ '%bops%'::text) THEN 'Submit to BOPS'::text
WHEN ((se.webhook_conf)::text ~~ '%uniform%'::text) THEN 'Submit to Uniform'::text
WHEN ((se.webhook_conf)::text ~~ '%email-submission%'::text) THEN 'Send to email'::text
WHEN ((se.webhook_conf)::text ~~ '%upload-submission%'::text) THEN 'Upload to AWS S3'::text
WHEN ((se.webhook_conf)::text ~~ '%idox%'::text) THEN 'Submit to Idox Nexus'::text
ELSE (se.webhook_conf)::text
END AS event_type,
CASE
WHEN (seil.status = 200) THEN 'Success'::text
ELSE format('Failed (%s)'::text, seil.status)
END AS status,
(seil.response)::jsonb AS response,
seil.created_at,
(EXISTS ( SELECT 1
FROM retries r
WHERE (r.id = seil.id))) AS retry
FROM (hdb_catalog.hdb_scheduled_events se
LEFT JOIN hdb_catalog.hdb_scheduled_event_invocation_logs seil ON ((seil.event_id = se.id)))
WHERE (((se.webhook_conf)::text !~~ '%email/%'::text) AND (seil.created_at >= '2024-01-01 00:00:00+00'::timestamp with time zone))
), all_events AS (
SELECT payments.session_id,
payments.event_id,
payments.event_type,
payments.status,
payments.response,
payments.created_at,
payments.retry
FROM payments
UNION ALL
SELECT submissions.session_id,
submissions.event_id,
submissions.event_type,
submissions.status,
submissions.response,
submissions.created_at,
submissions.retry
FROM submissions
)
SELECT ls.flow_id,
ae.session_id,
ae.event_id,
ae.event_type,
ae.status,
ae.response,
ae.created_at,
ae.retry
FROM (all_events ae
LEFT JOIN lowcal_sessions ls ON ((ls.id = ae.session_id)))
WHERE (ls.flow_id IS NOT NULL)
ORDER BY ae.created_at DESC;

0 comments on commit cdd8ad5

Please sign in to comment.