mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-20 08:11:13 -05:00
Fix notification logs migration
This commit is contained in:
@@ -1316,6 +1316,33 @@ export type Database = {
|
|||||||
}
|
}
|
||||||
Relationships: []
|
Relationships: []
|
||||||
}
|
}
|
||||||
|
notification_duplicate_stats: {
|
||||||
|
Row: {
|
||||||
|
created_at: string | null
|
||||||
|
date: string
|
||||||
|
duplicates_prevented: number | null
|
||||||
|
id: string
|
||||||
|
prevention_rate: number | null
|
||||||
|
total_attempts: number | null
|
||||||
|
}
|
||||||
|
Insert: {
|
||||||
|
created_at?: string | null
|
||||||
|
date?: string
|
||||||
|
duplicates_prevented?: number | null
|
||||||
|
id?: string
|
||||||
|
prevention_rate?: number | null
|
||||||
|
total_attempts?: number | null
|
||||||
|
}
|
||||||
|
Update: {
|
||||||
|
created_at?: string | null
|
||||||
|
date?: string
|
||||||
|
duplicates_prevented?: number | null
|
||||||
|
id?: string
|
||||||
|
prevention_rate?: number | null
|
||||||
|
total_attempts?: number | null
|
||||||
|
}
|
||||||
|
Relationships: []
|
||||||
|
}
|
||||||
notification_logs: {
|
notification_logs: {
|
||||||
Row: {
|
Row: {
|
||||||
channel: string
|
channel: string
|
||||||
@@ -1323,6 +1350,8 @@ export type Database = {
|
|||||||
delivered_at: string | null
|
delivered_at: string | null
|
||||||
error_message: string | null
|
error_message: string | null
|
||||||
id: string
|
id: string
|
||||||
|
idempotency_key: string | null
|
||||||
|
is_duplicate: boolean
|
||||||
novu_transaction_id: string | null
|
novu_transaction_id: string | null
|
||||||
payload: Json | null
|
payload: Json | null
|
||||||
read_at: string | null
|
read_at: string | null
|
||||||
@@ -1336,6 +1365,8 @@ export type Database = {
|
|||||||
delivered_at?: string | null
|
delivered_at?: string | null
|
||||||
error_message?: string | null
|
error_message?: string | null
|
||||||
id?: string
|
id?: string
|
||||||
|
idempotency_key?: string | null
|
||||||
|
is_duplicate?: boolean
|
||||||
novu_transaction_id?: string | null
|
novu_transaction_id?: string | null
|
||||||
payload?: Json | null
|
payload?: Json | null
|
||||||
read_at?: string | null
|
read_at?: string | null
|
||||||
@@ -1349,6 +1380,8 @@ export type Database = {
|
|||||||
delivered_at?: string | null
|
delivered_at?: string | null
|
||||||
error_message?: string | null
|
error_message?: string | null
|
||||||
id?: string
|
id?: string
|
||||||
|
idempotency_key?: string | null
|
||||||
|
is_duplicate?: boolean
|
||||||
novu_transaction_id?: string | null
|
novu_transaction_id?: string | null
|
||||||
payload?: Json | null
|
payload?: Json | null
|
||||||
read_at?: string | null
|
read_at?: string | null
|
||||||
@@ -4614,6 +4647,16 @@ export type Database = {
|
|||||||
}
|
}
|
||||||
Relationships: []
|
Relationships: []
|
||||||
}
|
}
|
||||||
|
notification_health_dashboard: {
|
||||||
|
Row: {
|
||||||
|
date: string | null
|
||||||
|
duplicates_prevented: number | null
|
||||||
|
health_status: string | null
|
||||||
|
prevention_rate: number | null
|
||||||
|
total_attempts: number | null
|
||||||
|
}
|
||||||
|
Relationships: []
|
||||||
|
}
|
||||||
}
|
}
|
||||||
Functions: {
|
Functions: {
|
||||||
anonymize_user_submissions: {
|
anonymize_user_submissions: {
|
||||||
@@ -4692,6 +4735,15 @@ export type Database = {
|
|||||||
}
|
}
|
||||||
extract_cf_image_id: { Args: { url: string }; Returns: string }
|
extract_cf_image_id: { Args: { url: string }; Returns: string }
|
||||||
generate_deletion_confirmation_code: { Args: never; Returns: string }
|
generate_deletion_confirmation_code: { Args: never; Returns: string }
|
||||||
|
generate_notification_idempotency_key: {
|
||||||
|
Args: {
|
||||||
|
p_entity_id: string
|
||||||
|
p_event_data?: Json
|
||||||
|
p_notification_type: string
|
||||||
|
p_recipient_id: string
|
||||||
|
}
|
||||||
|
Returns: string
|
||||||
|
}
|
||||||
generate_ticket_number: { Args: never; Returns: string }
|
generate_ticket_number: { Args: never; Returns: string }
|
||||||
get_auth0_sub_from_jwt: { Args: never; Returns: string }
|
get_auth0_sub_from_jwt: { Args: never; Returns: string }
|
||||||
get_current_user_id: { Args: never; Returns: string }
|
get_current_user_id: { Args: never; Returns: string }
|
||||||
@@ -4775,6 +4827,7 @@ export type Database = {
|
|||||||
}
|
}
|
||||||
hash_ip_address: { Args: { ip_text: string }; Returns: string }
|
hash_ip_address: { Args: { ip_text: string }; Returns: string }
|
||||||
hash_session_ip: { Args: { session_ip: unknown }; Returns: string }
|
hash_session_ip: { Args: { session_ip: unknown }; Returns: string }
|
||||||
|
immutable_date: { Args: { ts: string }; Returns: string }
|
||||||
increment_blog_view_count: {
|
increment_blog_view_count: {
|
||||||
Args: { post_slug: string }
|
Args: { post_slug: string }
|
||||||
Returns: undefined
|
Returns: undefined
|
||||||
|
|||||||
@@ -0,0 +1,89 @@
|
|||||||
|
-- Migration: Add notification idempotency and duplicate prevention
|
||||||
|
|
||||||
|
-- Add idempotency columns to notification_logs
|
||||||
|
ALTER TABLE public.notification_logs
|
||||||
|
ADD COLUMN IF NOT EXISTS idempotency_key TEXT,
|
||||||
|
ADD COLUMN IF NOT EXISTS is_duplicate BOOLEAN NOT NULL DEFAULT false;
|
||||||
|
|
||||||
|
-- Create immutable function for date extraction (required for index)
|
||||||
|
CREATE OR REPLACE FUNCTION public.immutable_date(ts TIMESTAMPTZ)
|
||||||
|
RETURNS DATE AS $$
|
||||||
|
BEGIN
|
||||||
|
RETURN ts::DATE;
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql IMMUTABLE SECURITY DEFINER SET search_path = public;
|
||||||
|
|
||||||
|
-- Create unique index to prevent duplicates (same key per user per day)
|
||||||
|
DROP INDEX IF EXISTS idx_notification_logs_idempotency_unique;
|
||||||
|
CREATE UNIQUE INDEX idx_notification_logs_idempotency_unique
|
||||||
|
ON public.notification_logs (user_id, idempotency_key, immutable_date(created_at))
|
||||||
|
WHERE idempotency_key IS NOT NULL;
|
||||||
|
|
||||||
|
-- Index for monitoring duplicates
|
||||||
|
CREATE INDEX IF NOT EXISTS idx_notification_logs_duplicates
|
||||||
|
ON public.notification_logs(is_duplicate, created_at)
|
||||||
|
WHERE is_duplicate = true;
|
||||||
|
|
||||||
|
-- Create duplicate tracking stats table
|
||||||
|
CREATE TABLE IF NOT EXISTS public.notification_duplicate_stats (
|
||||||
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||||
|
date DATE NOT NULL DEFAULT CURRENT_DATE,
|
||||||
|
total_attempts INTEGER DEFAULT 0,
|
||||||
|
duplicates_prevented INTEGER DEFAULT 0,
|
||||||
|
prevention_rate DECIMAL(5,2) GENERATED ALWAYS AS (
|
||||||
|
CASE
|
||||||
|
WHEN total_attempts > 0 THEN (duplicates_prevented::DECIMAL / total_attempts * 100)
|
||||||
|
ELSE 0
|
||||||
|
END
|
||||||
|
) STORED,
|
||||||
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||||
|
UNIQUE(date)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Enable RLS on duplicate stats
|
||||||
|
ALTER TABLE public.notification_duplicate_stats ENABLE ROW LEVEL SECURITY;
|
||||||
|
|
||||||
|
-- Drop and recreate policy
|
||||||
|
DROP POLICY IF EXISTS "Admins can view duplicate stats" ON public.notification_duplicate_stats;
|
||||||
|
CREATE POLICY "Admins can view duplicate stats"
|
||||||
|
ON public.notification_duplicate_stats FOR SELECT
|
||||||
|
USING (is_moderator(auth.uid()));
|
||||||
|
|
||||||
|
-- Function to generate idempotency key
|
||||||
|
CREATE OR REPLACE FUNCTION public.generate_notification_idempotency_key(
|
||||||
|
p_notification_type TEXT,
|
||||||
|
p_entity_id UUID,
|
||||||
|
p_recipient_id UUID,
|
||||||
|
p_event_data JSONB DEFAULT NULL
|
||||||
|
)
|
||||||
|
RETURNS TEXT AS $$
|
||||||
|
BEGIN
|
||||||
|
RETURN encode(
|
||||||
|
digest(
|
||||||
|
p_notification_type ||
|
||||||
|
COALESCE(p_entity_id::TEXT, '') ||
|
||||||
|
p_recipient_id::TEXT ||
|
||||||
|
CURRENT_DATE::TEXT ||
|
||||||
|
COALESCE(p_event_data::TEXT, ''),
|
||||||
|
'sha256'
|
||||||
|
),
|
||||||
|
'hex'
|
||||||
|
);
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql IMMUTABLE SECURITY DEFINER SET search_path = public;
|
||||||
|
|
||||||
|
-- Create monitoring view for notification health
|
||||||
|
CREATE OR REPLACE VIEW public.notification_health_dashboard AS
|
||||||
|
SELECT
|
||||||
|
date,
|
||||||
|
total_attempts,
|
||||||
|
duplicates_prevented,
|
||||||
|
prevention_rate,
|
||||||
|
CASE
|
||||||
|
WHEN prevention_rate > 10 THEN 'critical'
|
||||||
|
WHEN prevention_rate > 5 THEN 'warning'
|
||||||
|
ELSE 'healthy'
|
||||||
|
END as health_status
|
||||||
|
FROM public.notification_duplicate_stats
|
||||||
|
ORDER BY date DESC
|
||||||
|
LIMIT 30;
|
||||||
Reference in New Issue
Block a user