mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-20 06:31:13 -05:00
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.
113 lines
3.9 KiB
PL/PgSQL
113 lines
3.9 KiB
PL/PgSQL
-- 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; |