-- Protection 1: Transaction support for atomic submission + items creation CREATE OR REPLACE FUNCTION create_submission_with_items( p_user_id UUID, p_submission_type TEXT, p_content JSONB, p_items JSONB[] ) RETURNS UUID LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ DECLARE v_submission_id UUID; v_item JSONB; BEGIN -- Insert submission INSERT INTO content_submissions (user_id, submission_type, content, status, approval_mode) VALUES (p_user_id, p_submission_type, p_content, 'pending', 'full') RETURNING id INTO v_submission_id; -- Validate we have at least one item IF array_length(p_items, 1) IS NULL OR array_length(p_items, 1) = 0 THEN RAISE EXCEPTION 'Cannot create submission without items'; END IF; -- Insert all items atomically (fails entire transaction if any fail) FOREACH v_item IN ARRAY p_items LOOP INSERT INTO submission_items ( submission_id, item_type, action_type, item_data, original_data, status, order_index, depends_on ) VALUES ( v_submission_id, (v_item->>'item_type')::TEXT, (v_item->>'action_type')::TEXT, v_item->'item_data', v_item->'original_data', 'pending', COALESCE((v_item->>'order_index')::INTEGER, 0), (v_item->>'depends_on')::UUID ); END LOOP; RETURN v_submission_id; END; $$; -- Protection 3: Cleanup job for orphaned submissions CREATE OR REPLACE FUNCTION cleanup_orphaned_submissions() RETURNS INTEGER LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ DECLARE deleted_count INTEGER; BEGIN -- Delete submissions older than 1 hour with no items DELETE FROM content_submissions WHERE id IN ( SELECT cs.id FROM content_submissions cs LEFT JOIN submission_items si ON si.submission_id = cs.id WHERE si.id IS NULL AND cs.created_at < NOW() - INTERVAL '1 hour' AND cs.status = 'pending' ); GET DIAGNOSTICS deleted_count = ROW_COUNT; RAISE NOTICE 'Cleaned up % orphaned submissions', deleted_count; RETURN deleted_count; END; $$; -- Grant execute permissions GRANT EXECUTE ON FUNCTION create_submission_with_items TO authenticated; GRANT EXECUTE ON FUNCTION cleanup_orphaned_submissions TO service_role;