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

chore: create email_events_log view to access Hasura Event metadata #4211

Merged
merged 3 commits into from
Jan 27, 2025
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
3 changes: 3 additions & 0 deletions hasura.planx.uk/metadata/tables.yaml
Original file line number Diff line number Diff line change
Expand Up @@ -246,6 +246,9 @@
template_engine: Kriti
url: '{{$base_url}}/webhooks/hasura/send-slack-notification'
version: 2
- table:
name: email_events_log
schema: public
- table:
name: feedback
schema: public
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
DROP VIEW "public"."email_events_log";
Original file line number Diff line number Diff line change
@@ -0,0 +1,52 @@
CREATE OR REPLACE VIEW public.email_events_log AS
WITH 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))
), emails AS (
SELECT
((((seil.request -> 'payload'::text) -> 'payload'::text) ->> 'sessionId'::text))::uuid AS session_id,
se.id AS event_id,
CASE
WHEN ((webhook_conf)::text ~~ '%/send-email/expiry"'::text) THEN 'Session expiry'::text
WHEN ((webhook_conf)::text ~~ '%/send-email/reminder"'::text) THEN 'Session reminder'::text
WHEN ((webhook_conf)::text ~~ '%/send-email/confirmation"'::text) THEN 'Submission confirmation'::text
WHEN ((webhook_conf)::text ~~ '%/send-email/invite-to-pay"'::text) THEN 'Invitation to pay'::text
WHEN ((webhook_conf)::text ~~ '%/send-email/invite-to-pay-agent"'::text) THEN 'Invitation to pay - agent'::text
WHEN ((webhook_conf)::text ~~ '%/send-email/payment-expiry"'::text) THEN 'Payment expiry'::text
WHEN ((webhook_conf)::text ~~ '%/send-email/payment-expiry-agent"'::text) THEN 'Payment expiry - agent'::text
WHEN ((webhook_conf)::text ~~ '%/send-email/payment-reminder"'::text) THEN 'Payment reminder'::text
WHEN ((webhook_conf)::text ~~ '%/send-email/payment-reminder-agent"'::text) THEN 'Payment reminder - agent'::text
ELSE (webhook_conf)::text
Copy link
Contributor

@DafyddLlyr DafyddLlyr Jan 27, 2025

Choose a reason for hiding this comment

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

Great fallback to catch new templates or other issues.

The fact we have to parse this from here (but it's very useful information) suggests we should maybe consider capturing this more explicitly / pro-actively as an audit log when sending emails.

This is a really solid and practical solution though - love it 👍

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 ~~ '%/send-email/%'::text) AND (seil.created_at >= '2024-01-01 00:00:00+00'::timestamp with time zone))
)
SELECT
ls.flow_id,
e.session_id,
e.event_id,
e.event_type,
e.status,
e.response,
e.created_at,
e.retry
FROM (emails e LEFT JOIN lowcal_sessions ls ON ((ls.id = e.session_id)))
WHERE (ls.flow_id IS NOT NULL)
ORDER BY e.created_at DESC;
Loading