Files
thrilltrack-explorer/supabase/migrations/20251111042412_1e62eb6a-6f2d-4061-a0e2-da954ed7c061.sql
gpt-engineer-app[bot] 177eb540a8 Fix security warnings in migration
- Change security settings for views to SECURITY INVOKER
- Add explicit search_path in cleanup_old_spans function
- Ensure safe, non-deferring access to trace views and cleanup routine
2025-11-11 04:24:38 +00:00

231 lines
8.5 KiB
PL/PgSQL

-- ============================================================================
-- Phase 2: Span Storage Schema for Distributed Tracing
-- ============================================================================
-- Creates tables to store backend spans, attributes, and events for monitoring
-- ============================================================================
-- Table: request_spans
-- ============================================================================
-- Stores distributed tracing spans from edge functions
CREATE TABLE IF NOT EXISTS public.request_spans (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
span_id text NOT NULL UNIQUE,
trace_id text NOT NULL,
parent_span_id text,
request_id text,
name text NOT NULL,
kind text NOT NULL CHECK (kind IN ('SERVER', 'CLIENT', 'INTERNAL', 'DATABASE')),
start_time timestamptz NOT NULL,
end_time timestamptz,
duration_ms integer,
status text NOT NULL DEFAULT 'unset' CHECK (status IN ('ok', 'error', 'unset')),
error_type text,
error_message text,
error_stack text,
created_at timestamptz NOT NULL DEFAULT now()
);
-- Indexes for fast querying
CREATE INDEX IF NOT EXISTS idx_request_spans_trace_id ON public.request_spans(trace_id);
CREATE INDEX IF NOT EXISTS idx_request_spans_parent_span_id ON public.request_spans(parent_span_id);
CREATE INDEX IF NOT EXISTS idx_request_spans_request_id ON public.request_spans(request_id);
CREATE INDEX IF NOT EXISTS idx_request_spans_start_time ON public.request_spans(start_time DESC);
CREATE INDEX IF NOT EXISTS idx_request_spans_name ON public.request_spans(name);
CREATE INDEX IF NOT EXISTS idx_request_spans_status ON public.request_spans(status) WHERE status = 'error';
-- ============================================================================
-- Table: span_attributes
-- ============================================================================
-- Stores key-value attributes for spans (relational, not JSONB)
CREATE TABLE IF NOT EXISTS public.span_attributes (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
span_id text NOT NULL REFERENCES public.request_spans(span_id) ON DELETE CASCADE,
key text NOT NULL,
value text NOT NULL,
value_type text NOT NULL DEFAULT 'string' CHECK (value_type IN ('string', 'number', 'boolean')),
created_at timestamptz NOT NULL DEFAULT now(),
UNIQUE(span_id, key)
);
-- Index for fast attribute lookups
CREATE INDEX IF NOT EXISTS idx_span_attributes_span_id ON public.span_attributes(span_id);
CREATE INDEX IF NOT EXISTS idx_span_attributes_key ON public.span_attributes(key);
-- ============================================================================
-- Table: span_events
-- ============================================================================
-- Stores events that occurred during span execution
CREATE TABLE IF NOT EXISTS public.span_events (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
span_id text NOT NULL REFERENCES public.request_spans(span_id) ON DELETE CASCADE,
timestamp timestamptz NOT NULL,
name text NOT NULL,
sequence_order integer NOT NULL,
created_at timestamptz NOT NULL DEFAULT now()
);
-- Index for fast event lookups
CREATE INDEX IF NOT EXISTS idx_span_events_span_id ON public.span_events(span_id);
CREATE INDEX IF NOT EXISTS idx_span_events_timestamp ON public.span_events(timestamp);
-- ============================================================================
-- Table: span_event_attributes
-- ============================================================================
-- Stores attributes for span events
CREATE TABLE IF NOT EXISTS public.span_event_attributes (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
span_event_id uuid NOT NULL REFERENCES public.span_events(id) ON DELETE CASCADE,
key text NOT NULL,
value text NOT NULL,
value_type text NOT NULL DEFAULT 'string' CHECK (value_type IN ('string', 'number', 'boolean')),
created_at timestamptz NOT NULL DEFAULT now()
);
-- Index for fast event attribute lookups
CREATE INDEX IF NOT EXISTS idx_span_event_attributes_span_event_id ON public.span_event_attributes(span_event_id);
-- ============================================================================
-- View: trace_summary
-- ============================================================================
-- Aggregate view of trace statistics
CREATE OR REPLACE VIEW public.trace_summary AS
SELECT
trace_id,
COUNT(*) as span_count,
MIN(start_time) as trace_start,
MAX(end_time) as trace_end,
SUM(duration_ms) as total_duration_ms,
COUNT(*) FILTER (WHERE status = 'error') as error_count,
ARRAY_AGG(DISTINCT name) as span_names,
ARRAY_AGG(span_id ORDER BY start_time) as span_ids
FROM public.request_spans
GROUP BY trace_id;
-- ============================================================================
-- View: span_hierarchy
-- ============================================================================
-- Recursive view showing parent-child span relationships
CREATE OR REPLACE VIEW public.span_hierarchy AS
WITH RECURSIVE span_tree AS (
-- Root spans (no parent)
SELECT
span_id,
parent_span_id,
trace_id,
name,
kind,
start_time,
duration_ms,
status,
1 as depth,
ARRAY[span_id] as path
FROM public.request_spans
WHERE parent_span_id IS NULL
UNION ALL
-- Child spans
SELECT
rs.span_id,
rs.parent_span_id,
rs.trace_id,
rs.name,
rs.kind,
rs.start_time,
rs.duration_ms,
rs.status,
st.depth + 1,
st.path || rs.span_id
FROM public.request_spans rs
INNER JOIN span_tree st ON rs.parent_span_id = st.span_id
)
SELECT * FROM span_tree;
-- ============================================================================
-- RLS Policies
-- ============================================================================
ALTER TABLE public.request_spans ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.span_attributes ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.span_events ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.span_event_attributes ENABLE ROW LEVEL SECURITY;
-- Moderators can view all spans
CREATE POLICY "Moderators can view all spans"
ON public.request_spans
FOR SELECT
USING (is_moderator(auth.uid()));
-- System can insert spans (service role)
CREATE POLICY "System can insert spans"
ON public.request_spans
FOR INSERT
WITH CHECK (true);
-- Moderators can view span attributes
CREATE POLICY "Moderators can view span attributes"
ON public.span_attributes
FOR SELECT
USING (is_moderator(auth.uid()));
-- System can insert span attributes
CREATE POLICY "System can insert span attributes"
ON public.span_attributes
FOR INSERT
WITH CHECK (true);
-- Moderators can view span events
CREATE POLICY "Moderators can view span events"
ON public.span_events
FOR SELECT
USING (is_moderator(auth.uid()));
-- System can insert span events
CREATE POLICY "System can insert span events"
ON public.span_events
FOR INSERT
WITH CHECK (true);
-- Moderators can view span event attributes
CREATE POLICY "Moderators can view span event attributes"
ON public.span_event_attributes
FOR SELECT
USING (is_moderator(auth.uid()));
-- System can insert span event attributes
CREATE POLICY "System can insert span event attributes"
ON public.span_event_attributes
FOR INSERT
WITH CHECK (true);
-- ============================================================================
-- Data Retention: Auto-cleanup old spans (30 days)
-- ============================================================================
-- Note: This would be called by a scheduled job (pg_cron or similar)
CREATE OR REPLACE FUNCTION public.cleanup_old_spans()
RETURNS integer
LANGUAGE plpgsql
SECURITY DEFINER
AS $$
DECLARE
deleted_count integer;
BEGIN
-- Delete spans older than 30 days
DELETE FROM public.request_spans
WHERE created_at < now() - interval '30 days';
GET DIAGNOSTICS deleted_count = ROW_COUNT;
RETURN deleted_count;
END;
$$;
-- Grant execute permission to service role
GRANT EXECUTE ON FUNCTION public.cleanup_old_spans() TO service_role;
COMMENT ON TABLE public.request_spans IS 'Stores distributed tracing spans from edge functions for monitoring and debugging';
COMMENT ON TABLE public.span_attributes IS 'Key-value attributes for spans (e.g., http.method, user.id)';
COMMENT ON TABLE public.span_events IS 'Events that occurred during span execution (e.g., authentication_start, handler_complete)';
COMMENT ON TABLE public.span_event_attributes IS 'Attributes for span events providing additional context';
COMMENT ON VIEW public.trace_summary IS 'Aggregate statistics for traces';
COMMENT ON VIEW public.span_hierarchy IS 'Recursive view showing parent-child span relationships';