From 93a3fb93fa891f9efb554dfaade060ebaa959d50 Mon Sep 17 00:00:00 2001 From: "gpt-engineer-app[bot]" <159125892+gpt-engineer-app[bot]@users.noreply.github.com> Date: Thu, 6 Nov 2025 16:29:03 +0000 Subject: [PATCH] Fix: Correct idempotency key migration Corrected database migration for idempotency keys to resolve issues with partial indexes using `now()`. The migration now includes the `submission_idempotency_keys` table, indexes, RLS policies, a cleanup function, and an `idempotency_stats` view. --- src/integrations/supabase/types.ts | 78 ++++++++++++ ...2_7696685c-f666-4060-a791-c8a894eef13b.sql | 113 ++++++++++++++++++ 2 files changed, 191 insertions(+) create mode 100644 supabase/migrations/20251106162832_7696685c-f666-4060-a791-c8a894eef13b.sql diff --git a/src/integrations/supabase/types.ts b/src/integrations/supabase/types.ts index 14b06a44..dbfecef1 100644 --- a/src/integrations/supabase/types.ts +++ b/src/integrations/supabase/types.ts @@ -4908,6 +4908,72 @@ export type Database = { } Relationships: [] } + submission_idempotency_keys: { + Row: { + completed_at: string | null + created_at: string + duration_ms: number | null + error_message: string | null + expires_at: string + id: string + idempotency_key: string + item_ids: Json + moderator_id: string + request_id: string | null + result_data: Json | null + status: string + submission_id: string + trace_id: string | null + } + Insert: { + completed_at?: string | null + created_at?: string + duration_ms?: number | null + error_message?: string | null + expires_at?: string + id?: string + idempotency_key: string + item_ids: Json + moderator_id: string + request_id?: string | null + result_data?: Json | null + status?: string + submission_id: string + trace_id?: string | null + } + Update: { + completed_at?: string | null + created_at?: string + duration_ms?: number | null + error_message?: string | null + expires_at?: string + id?: string + idempotency_key?: string + item_ids?: Json + moderator_id?: string + request_id?: string | null + result_data?: Json | null + status?: string + submission_id?: string + trace_id?: string | null + } + Relationships: [ + { + foreignKeyName: "submission_idempotency_keys_submission_id_fkey" + columns: ["submission_id"] + isOneToOne: false + referencedRelation: "content_submissions" + referencedColumns: ["id"] + }, + { + foreignKeyName: "submission_idempotency_keys_submission_id_fkey" + columns: ["submission_id"] + isOneToOne: false + referencedRelation: "moderation_queue_with_entities" + referencedColumns: ["id"] + }, + ] + } submission_item_temp_refs: { Row: { created_at: string @@ -5603,6 +5669,17 @@ export type Database = { } Relationships: [] } + idempotency_stats: { + Row: { + avg_duration_ms: number | null + hour: string | null + p95_duration_ms: number | null + status: string | null + total_requests: number | null + unique_moderators: number | null + } + Relationships: [] + } moderation_queue_with_entities: { Row: { approval_mode: string | null @@ -5783,6 +5860,7 @@ export type Database = { } Returns: boolean } + cleanup_expired_idempotency_keys: { Args: never; Returns: number } cleanup_expired_sessions: { Args: never; Returns: undefined } cleanup_old_page_views: { Args: never; Returns: undefined } cleanup_old_request_metadata: { Args: never; Returns: undefined } diff --git a/supabase/migrations/20251106162832_7696685c-f666-4060-a791-c8a894eef13b.sql b/supabase/migrations/20251106162832_7696685c-f666-4060-a791-c8a894eef13b.sql new file mode 100644 index 00000000..168da6d6 --- /dev/null +++ b/supabase/migrations/20251106162832_7696685c-f666-4060-a791-c8a894eef13b.sql @@ -0,0 +1,113 @@ +-- Create submission_idempotency_keys table for preventing duplicate approvals +CREATE TABLE public.submission_idempotency_keys ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + idempotency_key TEXT NOT NULL, + submission_id UUID NOT NULL REFERENCES content_submissions(id) ON DELETE CASCADE, + moderator_id UUID NOT NULL, + item_ids JSONB NOT NULL, + + -- Result caching + status TEXT NOT NULL DEFAULT 'processing', + result_data JSONB, + error_message TEXT, + + -- Tracking + created_at TIMESTAMPTZ NOT NULL DEFAULT now(), + completed_at TIMESTAMPTZ, + expires_at TIMESTAMPTZ NOT NULL DEFAULT (now() + interval '24 hours'), + + -- Request metadata + request_id TEXT, + trace_id TEXT, + duration_ms INTEGER, + + CONSTRAINT unique_idempotency_key UNIQUE (idempotency_key, moderator_id), + CONSTRAINT valid_status CHECK (status IN ('processing', 'completed', 'failed')) +); + +COMMENT ON TABLE public.submission_idempotency_keys IS 'Prevents duplicate entity creation from rapid clicking or network retries'; +COMMENT ON COLUMN public.submission_idempotency_keys.idempotency_key IS 'Client-provided or generated unique key for the approval request'; +COMMENT ON COLUMN public.submission_idempotency_keys.item_ids IS 'JSONB array of submission item IDs being approved'; +COMMENT ON COLUMN public.submission_idempotency_keys.result_data IS 'Cached response for completed requests (returned on duplicate)'; +COMMENT ON COLUMN public.submission_idempotency_keys.expires_at IS 'Keys expire after 24 hours'; + +-- Primary lookup index +CREATE INDEX idx_idempotency_keys_lookup + ON submission_idempotency_keys(idempotency_key, moderator_id, expires_at); + +-- Cleanup/expiration index +CREATE INDEX idx_idempotency_keys_expiration + ON submission_idempotency_keys(expires_at); + +-- Analytics index +CREATE INDEX idx_idempotency_keys_submission + ON submission_idempotency_keys(submission_id, created_at DESC); + +-- Status monitoring index (only index processing items) +CREATE INDEX idx_idempotency_keys_status + ON submission_idempotency_keys(status, created_at) + WHERE status = 'processing'; + +-- Enable RLS +ALTER TABLE submission_idempotency_keys ENABLE ROW LEVEL SECURITY; + +-- Moderators can view their own keys +CREATE POLICY "Moderators view own idempotency keys" + ON submission_idempotency_keys FOR SELECT + USING ( + moderator_id = auth.uid() + AND is_moderator(auth.uid()) + ); + +-- System (edge function with service role) can insert keys +CREATE POLICY "System can insert idempotency keys" + ON submission_idempotency_keys FOR INSERT + WITH CHECK (true); + +-- System can update keys (status transitions) +CREATE POLICY "System can update idempotency keys" + ON submission_idempotency_keys FOR UPDATE + USING (true); + +-- Admins can view all keys for debugging +CREATE POLICY "Admins view all idempotency keys" + ON submission_idempotency_keys FOR SELECT + USING ( + has_role(auth.uid(), 'admin') + OR has_role(auth.uid(), 'superuser') + ); + +-- Function to clean up expired keys +CREATE OR REPLACE FUNCTION cleanup_expired_idempotency_keys() +RETURNS INTEGER +LANGUAGE plpgsql +SECURITY DEFINER +AS $$ +DECLARE + deleted_count INTEGER; +BEGIN + DELETE FROM submission_idempotency_keys + WHERE expires_at < now() - interval '1 hour'; + + GET DIAGNOSTICS deleted_count = ROW_COUNT; + + RETURN deleted_count; +END; +$$; + +COMMENT ON FUNCTION cleanup_expired_idempotency_keys() IS + 'Deletes idempotency keys that expired more than 1 hour ago. Run via pg_cron or scheduled job.'; + +-- Create monitoring view for analytics +CREATE OR REPLACE VIEW idempotency_stats AS +SELECT + DATE_TRUNC('hour', created_at) AS hour, + status, + COUNT(*) AS total_requests, + COUNT(DISTINCT moderator_id) AS unique_moderators, + AVG(duration_ms) AS avg_duration_ms, + PERCENTILE_CONT(0.95) WITHIN GROUP (ORDER BY duration_ms) AS p95_duration_ms +FROM submission_idempotency_keys +WHERE created_at > now() - interval '7 days' +GROUP BY DATE_TRUNC('hour', created_at), status +ORDER BY hour DESC, status; \ No newline at end of file