mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-20 10:31:13 -05:00
145 lines
3.6 KiB
PL/PgSQL
145 lines
3.6 KiB
PL/PgSQL
-- Phase 1.1: Add Explicit INSERT/UPDATE Denial Policies
|
|
-- These policies make it IMPOSSIBLE to bypass the submission flow
|
|
|
|
-- Parks table - block direct writes
|
|
CREATE POLICY "Deny direct inserts to parks"
|
|
ON public.parks FOR INSERT
|
|
TO authenticated
|
|
WITH CHECK (false);
|
|
|
|
CREATE POLICY "Deny direct updates to parks"
|
|
ON public.parks FOR UPDATE
|
|
TO authenticated
|
|
USING (false);
|
|
|
|
-- Rides table - block direct writes
|
|
CREATE POLICY "Deny direct inserts to rides"
|
|
ON public.rides FOR INSERT
|
|
TO authenticated
|
|
WITH CHECK (false);
|
|
|
|
CREATE POLICY "Deny direct updates to rides"
|
|
ON public.rides FOR UPDATE
|
|
TO authenticated
|
|
USING (false);
|
|
|
|
-- Companies table - block direct writes
|
|
CREATE POLICY "Deny direct inserts to companies"
|
|
ON public.companies FOR INSERT
|
|
TO authenticated
|
|
WITH CHECK (false);
|
|
|
|
CREATE POLICY "Deny direct updates to companies"
|
|
ON public.companies FOR UPDATE
|
|
TO authenticated
|
|
USING (false);
|
|
|
|
-- Ride models table - block direct writes
|
|
CREATE POLICY "Deny direct inserts to ride_models"
|
|
ON public.ride_models FOR INSERT
|
|
TO authenticated
|
|
WITH CHECK (false);
|
|
|
|
CREATE POLICY "Deny direct updates to ride_models"
|
|
ON public.ride_models FOR UPDATE
|
|
TO authenticated
|
|
USING (false);
|
|
|
|
-- Phase 1.2: Add Versioning for Photos Table
|
|
DROP TRIGGER IF EXISTS auto_version_photos ON public.photos;
|
|
CREATE TRIGGER auto_version_photos
|
|
AFTER INSERT OR UPDATE ON public.photos
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION public.auto_create_entity_version();
|
|
|
|
-- Update auto_create_entity_version to handle photos
|
|
CREATE OR REPLACE FUNCTION public.auto_create_entity_version()
|
|
RETURNS trigger
|
|
LANGUAGE plpgsql
|
|
SECURITY DEFINER
|
|
SET search_path = public
|
|
AS $function$
|
|
DECLARE
|
|
v_entity_type TEXT;
|
|
v_change_type version_change_type;
|
|
v_user_id UUID;
|
|
v_version_data JSONB;
|
|
BEGIN
|
|
-- Determine entity type from table name
|
|
v_entity_type := CASE TG_TABLE_NAME
|
|
WHEN 'parks' THEN 'park'
|
|
WHEN 'rides' THEN 'ride'
|
|
WHEN 'companies' THEN 'company'
|
|
WHEN 'ride_models' THEN 'ride_model'
|
|
WHEN 'photos' THEN 'photo'
|
|
ELSE substring(TG_TABLE_NAME from 1 for length(TG_TABLE_NAME) - 1)
|
|
END;
|
|
|
|
-- Determine change type
|
|
v_change_type := CASE TG_OP
|
|
WHEN 'INSERT' THEN 'created'::version_change_type
|
|
WHEN 'UPDATE' THEN 'updated'::version_change_type
|
|
ELSE 'updated'::version_change_type
|
|
END;
|
|
|
|
-- Get user from session or auth context
|
|
BEGIN
|
|
v_user_id := current_setting('app.current_user_id', true)::UUID;
|
|
EXCEPTION WHEN OTHERS THEN
|
|
v_user_id := auth.uid();
|
|
END;
|
|
|
|
-- Convert NEW record to JSONB
|
|
v_version_data := to_jsonb(NEW);
|
|
|
|
-- Create version (only if we have a user context)
|
|
IF v_user_id IS NOT NULL THEN
|
|
PERFORM public.create_entity_version(
|
|
v_entity_type,
|
|
NEW.id,
|
|
v_version_data,
|
|
v_user_id,
|
|
CASE TG_OP
|
|
WHEN 'INSERT' THEN 'Entity created'
|
|
WHEN 'UPDATE' THEN 'Entity updated'
|
|
ELSE 'Entity modified'
|
|
END,
|
|
NULL,
|
|
v_change_type
|
|
);
|
|
ELSE
|
|
-- Log suspicious version without user
|
|
INSERT INTO admin_audit_log (
|
|
action,
|
|
details,
|
|
created_at
|
|
) VALUES (
|
|
'version_without_user',
|
|
jsonb_build_object(
|
|
'entity_type', v_entity_type,
|
|
'entity_id', NEW.id,
|
|
'table', TG_TABLE_NAME,
|
|
'operation', TG_OP
|
|
),
|
|
NOW()
|
|
);
|
|
END IF;
|
|
|
|
RETURN NEW;
|
|
END;
|
|
$function$;
|
|
|
|
-- Phase 1.3: Create set_config helper for edge function
|
|
CREATE OR REPLACE FUNCTION public.set_config_value(
|
|
setting_name text,
|
|
setting_value text,
|
|
is_local boolean DEFAULT false
|
|
)
|
|
RETURNS void
|
|
LANGUAGE plpgsql
|
|
SECURITY DEFINER
|
|
AS $$
|
|
BEGIN
|
|
PERFORM set_config(setting_name, setting_value, is_local);
|
|
END;
|
|
$$; |