SET statement_timeout = 0; SET lock_timeout = 0; SET idle_in_transaction_session_timeout = 0; SET client_encoding = 'UTF8'; SET standard_conforming_strings = on; SELECT pg_catalog.set_config('search_path', '', false); SET check_function_bodies = false; SET xmloption = content; SET client_min_messages = warning; SET row_security = off; CREATE EXTENSION IF NOT EXISTS "pg_cron" WITH SCHEMA "pg_catalog"; COMMENT ON SCHEMA "public" IS 'standard public schema'; CREATE EXTENSION IF NOT EXISTS "pg_graphql" WITH SCHEMA "graphql"; CREATE EXTENSION IF NOT EXISTS "pg_stat_statements" WITH SCHEMA "extensions"; CREATE EXTENSION IF NOT EXISTS "pgcrypto" WITH SCHEMA "extensions"; CREATE EXTENSION IF NOT EXISTS "pgjwt" WITH SCHEMA "extensions"; CREATE EXTENSION IF NOT EXISTS "supabase_vault" WITH SCHEMA "vault"; CREATE EXTENSION IF NOT EXISTS "uuid-ossp" WITH SCHEMA "extensions"; CREATE TYPE "public"."section_posititon" AS ENUM ( 'events_manager', 'member' ); ALTER TYPE "public"."section_posititon" OWNER TO "postgres"; CREATE OR REPLACE FUNCTION "public"."archive_event"("_event_id" "uuid") RETURNS "void" LANGUAGE "plpgsql" SECURITY DEFINER AS $$ DECLARE v_total bigint; v_scanned bigint; v_evt public.events%ROWTYPE; BEGIN ------------------------------------------------------------------------- -- A. Fetch the event ------------------------------------------------------------------------- SELECT * INTO v_evt FROM public.events WHERE id = _event_id; IF NOT FOUND THEN RAISE EXCEPTION 'archive_event_and_delete(): event % does not exist', _event_id; END IF; ------------------------------------------------------------------------- -- B. Count participants ------------------------------------------------------------------------- SELECT COUNT(*) AS total, COUNT(*) FILTER (WHERE scanned) AS scanned INTO v_total, v_scanned FROM public.participants WHERE event = _event_id; ------------------------------------------------------------------------- -- C. Upsert into events_archived (now with section_id) ------------------------------------------------------------------------- INSERT INTO public.events_archived ( id, created_at, date, name, section_id, total_participants, scanned_participants ) VALUES ( v_evt.id, clock_timestamp(), v_evt.date, v_evt.name, v_evt.section_id, v_total, v_scanned ) ON CONFLICT (id) DO UPDATE SET created_at = EXCLUDED.created_at, date = EXCLUDED.date, name = EXCLUDED.name, section_id = EXCLUDED.section_id, total_participants = EXCLUDED.total_participants, scanned_participants= EXCLUDED.scanned_participants; ------------------------------------------------------------------------- -- D. Delete original event row (participants cascade away) ------------------------------------------------------------------------- DELETE FROM public.events WHERE id = _event_id; END; $$; ALTER FUNCTION "public"."archive_event"("_event_id" "uuid") OWNER TO "postgres"; CREATE OR REPLACE FUNCTION "public"."auto_archive_events"("_age_days" integer DEFAULT 7) RETURNS integer LANGUAGE "plpgsql" SECURITY DEFINER AS $$ DECLARE v_cnt int := 0; v_event_id uuid; BEGIN FOR v_event_id IN SELECT id FROM public.events WHERE date IS NOT NULL AND date <= CURRENT_DATE - _age_days LOOP BEGIN PERFORM public.archive_event(v_event_id); v_cnt := v_cnt + 1; EXCEPTION WHEN others THEN -- Optionally record the failure somewhere and continue RAISE WARNING 'Failed to archive event %, %', v_event_id, SQLERRM; END; END LOOP; RETURN v_cnt; END; $$; ALTER FUNCTION "public"."auto_archive_events"("_age_days" integer) OWNER TO "postgres"; SET default_tablespace = ''; SET default_table_access_method = "heap"; CREATE TABLE IF NOT EXISTS "public"."events" ( "id" "uuid" DEFAULT "gen_random_uuid"() NOT NULL, "created_at" timestamp with time zone DEFAULT "now"() NOT NULL, "created_by" "uuid" DEFAULT "auth"."uid"(), "name" "text", "date" "date", "section_id" "uuid" ); ALTER TABLE "public"."events" OWNER TO "postgres"; COMMENT ON TABLE "public"."events" IS 'Table of all events created'; CREATE OR REPLACE FUNCTION "public"."create_event"("p_name" "text", "p_date" "date") RETURNS "public"."events" LANGUAGE "plpgsql" SECURITY DEFINER SET "search_path" TO 'public' AS $$ declare v_user uuid := auth.uid(); -- current user v_section uuid; -- their section_id v_evt public.events%rowtype; -- the inserted event begin -- 1) lookup the user's section select section_id into v_section from public.profiles where id = v_user; if v_section is null then raise exception 'no profile/section found for user %', v_user; end if; -- 2) insert into events, filling created_by and section_id insert into public.events ( name, date, created_by, section_id ) values ( p_name, p_date, v_user, v_section ) returning * into v_evt; -- 3) return the full row return v_evt; end; $$; ALTER FUNCTION "public"."create_event"("p_name" "text", "p_date" "date") OWNER TO "postgres"; CREATE TABLE IF NOT EXISTS "public"."participants" ( "id" "uuid" DEFAULT "gen_random_uuid"() NOT NULL, "created_at" timestamp with time zone DEFAULT "now"() NOT NULL, "created_by" "uuid" DEFAULT "auth"."uid"(), "event" "uuid", "name" "text", "surname" "text", "email" "text", "scanned" boolean DEFAULT false, "scanned_at" timestamp with time zone, "scanned_by" "uuid", "section_id" "uuid" ); ALTER TABLE "public"."participants" OWNER TO "postgres"; COMMENT ON TABLE "public"."participants" IS 'Table of all qrcodes issued'; CREATE OR REPLACE FUNCTION "public"."create_qrcodes_bulk"("p_section_id" "uuid", "p_event_id" "uuid", "p_names" "text"[], "p_surnames" "text"[], "p_emails" "text"[]) RETURNS SETOF "public"."participants" LANGUAGE "plpgsql" SECURITY DEFINER SET "search_path" TO 'public', 'pg_temp' AS $$BEGIN ----------------------------------------------------------------- -- 1) keep the array-length check exactly as before ----------------------------------------------------------------- IF array_length(p_names, 1) IS DISTINCT FROM array_length(p_surnames,1) OR array_length(p_names, 1) IS DISTINCT FROM array_length(p_emails, 1) THEN RAISE EXCEPTION 'Names, surnames and emails arrays must all be the same length'; END IF; RETURN QUERY INSERT INTO public.participants (section_id, event, name, surname, email) SELECT p_section_id, p_event_id, n, s, e FROM unnest(p_names, p_surnames, p_emails) AS u(n, s, e) RETURNING *; END;$$; ALTER FUNCTION "public"."create_qrcodes_bulk"("p_section_id" "uuid", "p_event_id" "uuid", "p_names" "text"[], "p_surnames" "text"[], "p_emails" "text"[]) OWNER TO "postgres"; CREATE OR REPLACE FUNCTION "public"."handle_new_user"() RETURNS "trigger" LANGUAGE "plpgsql" SECURITY DEFINER SET "search_path" TO 'public', 'auth' AS $$begin insert into public.profiles(id, display_name, created_at, updated_at) values (new.id, coalesce(new.raw_user_meta_data ->> 'display_name', -- meta-data name if present split_part(new.email, '@', 1)), -- fallback: part of the email now(), now()); return new; end;$$; ALTER FUNCTION "public"."handle_new_user"() OWNER TO "postgres"; CREATE OR REPLACE FUNCTION "public"."scan_ticket"("_ticket_id" "uuid") RETURNS "void" LANGUAGE "plpgsql" SECURITY DEFINER SET "search_path" TO 'public' AS $$BEGIN UPDATE participants SET scanned = true, scanned_at = NOW(), scanned_by = auth.uid() WHERE id = _ticket_id; -- optionally, make sure exactly one row was updated IF NOT FOUND THEN RAISE EXCEPTION 'Ticket % not found or already scanned', _ticket_id; END IF; END;$$; ALTER FUNCTION "public"."scan_ticket"("_ticket_id" "uuid") OWNER TO "postgres"; CREATE TABLE IF NOT EXISTS "public"."events_archived" ( "id" "uuid" DEFAULT "gen_random_uuid"() NOT NULL, "created_at" timestamp with time zone DEFAULT "now"() NOT NULL, "date" "date", "name" "text" NOT NULL, "total_participants" numeric, "scanned_participants" numeric, "section_id" "uuid" ); ALTER TABLE "public"."events_archived" OWNER TO "postgres"; CREATE TABLE IF NOT EXISTS "public"."profiles" ( "id" "uuid" NOT NULL, "display_name" "text", "created_at" timestamp with time zone DEFAULT "now"(), "updated_at" timestamp with time zone DEFAULT "now"(), "section_id" "uuid", "section_position" "public"."section_posititon" DEFAULT 'member'::"public"."section_posititon" NOT NULL ); ALTER TABLE "public"."profiles" OWNER TO "postgres"; CREATE TABLE IF NOT EXISTS "public"."sections" ( "id" "uuid" DEFAULT "gen_random_uuid"() NOT NULL, "created_at" timestamp with time zone DEFAULT "now"() NOT NULL, "name" "text" NOT NULL ); ALTER TABLE "public"."sections" OWNER TO "postgres"; COMMENT ON TABLE "public"."sections" IS 'List of ESN sections using the app'; ALTER TABLE ONLY "public"."events_archived" ADD CONSTRAINT "events_archived_pkey" PRIMARY KEY ("id"); ALTER TABLE ONLY "public"."events" ADD CONSTRAINT "events_pkey" PRIMARY KEY ("id"); ALTER TABLE ONLY "public"."profiles" ADD CONSTRAINT "profiles_pkey" PRIMARY KEY ("id"); ALTER TABLE ONLY "public"."participants" ADD CONSTRAINT "qrcodes_pkey" PRIMARY KEY ("id"); ALTER TABLE ONLY "public"."sections" ADD CONSTRAINT "sections_name_key" UNIQUE ("name"); ALTER TABLE ONLY "public"."sections" ADD CONSTRAINT "sections_pkey" PRIMARY KEY ("id"); ALTER TABLE ONLY "public"."events_archived" ADD CONSTRAINT "events_archived_section_id_fkey" FOREIGN KEY ("section_id") REFERENCES "public"."sections"("id") ON DELETE CASCADE; ALTER TABLE ONLY "public"."events" ADD CONSTRAINT "events_created_by_fkey" FOREIGN KEY ("created_by") REFERENCES "auth"."users"("id"); ALTER TABLE ONLY "public"."events" ADD CONSTRAINT "events_section_id_fkey" FOREIGN KEY ("section_id") REFERENCES "public"."sections"("id") ON DELETE CASCADE; ALTER TABLE ONLY "public"."participants" ADD CONSTRAINT "participants_created_by_fkey" FOREIGN KEY ("created_by") REFERENCES "auth"."users"("id") ON DELETE CASCADE; ALTER TABLE ONLY "public"."participants" ADD CONSTRAINT "participants_event_fkey" FOREIGN KEY ("event") REFERENCES "public"."events"("id") ON DELETE CASCADE; ALTER TABLE ONLY "public"."participants" ADD CONSTRAINT "participants_scanned_by_fkey" FOREIGN KEY ("scanned_by") REFERENCES "public"."profiles"("id") ON DELETE CASCADE; ALTER TABLE ONLY "public"."profiles" ADD CONSTRAINT "profiles_id_fkey" FOREIGN KEY ("id") REFERENCES "auth"."users"("id") ON DELETE CASCADE; ALTER TABLE ONLY "public"."profiles" ADD CONSTRAINT "profiles_section_id_fkey" FOREIGN KEY ("section_id") REFERENCES "public"."sections"("id") ON DELETE CASCADE; ALTER TABLE ONLY "public"."participants" ADD CONSTRAINT "qrcodes_scanned_by_fkey" FOREIGN KEY ("scanned_by") REFERENCES "auth"."users"("id"); ALTER TABLE ONLY "public"."participants" ADD CONSTRAINT "qrcodes_section_id_fkey" FOREIGN KEY ("section_id") REFERENCES "public"."sections"("id") ON DELETE CASCADE; CREATE POLICY "Access only to section resources" ON "public"."events_archived" FOR SELECT TO "authenticated" USING ((EXISTS ( SELECT 1 FROM "public"."profiles" "p" WHERE ("p"."section_id" = "events_archived"."section_id")))); CREATE POLICY "Enable select for authenticated users only" ON "public"."profiles" FOR SELECT TO "authenticated" USING (true); CREATE POLICY "Enable select for authenticated users only" ON "public"."sections" FOR SELECT TO "authenticated" USING (true); CREATE POLICY "Only display section resources" ON "public"."events" FOR SELECT TO "authenticated" USING ((EXISTS ( SELECT 1 FROM "public"."profiles" "p" WHERE ("p"."section_id" = "events"."section_id")))); CREATE POLICY "Only display section resources" ON "public"."participants" FOR SELECT TO "authenticated" USING ((EXISTS ( SELECT 1 FROM "public"."profiles" "p" WHERE ("p"."section_id" = "participants"."section_id")))); ALTER TABLE "public"."events" ENABLE ROW LEVEL SECURITY; ALTER TABLE "public"."events_archived" ENABLE ROW LEVEL SECURITY; ALTER TABLE "public"."participants" ENABLE ROW LEVEL SECURITY; ALTER TABLE "public"."profiles" ENABLE ROW LEVEL SECURITY; ALTER TABLE "public"."sections" ENABLE ROW LEVEL SECURITY; ALTER PUBLICATION "supabase_realtime" OWNER TO "postgres"; GRANT USAGE ON SCHEMA "public" TO "postgres"; GRANT USAGE ON SCHEMA "public" TO "anon"; GRANT USAGE ON SCHEMA "public" TO "authenticated"; GRANT USAGE ON SCHEMA "public" TO "service_role"; GRANT ALL ON FUNCTION "public"."archive_event"("_event_id" "uuid") TO "anon"; GRANT ALL ON FUNCTION "public"."archive_event"("_event_id" "uuid") TO "authenticated"; GRANT ALL ON FUNCTION "public"."archive_event"("_event_id" "uuid") TO "service_role"; GRANT ALL ON FUNCTION "public"."auto_archive_events"("_age_days" integer) TO "anon"; GRANT ALL ON FUNCTION "public"."auto_archive_events"("_age_days" integer) TO "authenticated"; GRANT ALL ON FUNCTION "public"."auto_archive_events"("_age_days" integer) TO "service_role"; GRANT ALL ON TABLE "public"."events" TO "anon"; GRANT ALL ON TABLE "public"."events" TO "authenticated"; GRANT ALL ON TABLE "public"."events" TO "service_role"; GRANT ALL ON FUNCTION "public"."create_event"("p_name" "text", "p_date" "date") TO "anon"; GRANT ALL ON FUNCTION "public"."create_event"("p_name" "text", "p_date" "date") TO "authenticated"; GRANT ALL ON FUNCTION "public"."create_event"("p_name" "text", "p_date" "date") TO "service_role"; GRANT ALL ON TABLE "public"."participants" TO "anon"; GRANT ALL ON TABLE "public"."participants" TO "authenticated"; GRANT ALL ON TABLE "public"."participants" TO "service_role"; GRANT ALL ON FUNCTION "public"."create_qrcodes_bulk"("p_section_id" "uuid", "p_event_id" "uuid", "p_names" "text"[], "p_surnames" "text"[], "p_emails" "text"[]) TO "anon"; GRANT ALL ON FUNCTION "public"."create_qrcodes_bulk"("p_section_id" "uuid", "p_event_id" "uuid", "p_names" "text"[], "p_surnames" "text"[], "p_emails" "text"[]) TO "authenticated"; GRANT ALL ON FUNCTION "public"."create_qrcodes_bulk"("p_section_id" "uuid", "p_event_id" "uuid", "p_names" "text"[], "p_surnames" "text"[], "p_emails" "text"[]) TO "service_role"; GRANT ALL ON FUNCTION "public"."handle_new_user"() TO "anon"; GRANT ALL ON FUNCTION "public"."handle_new_user"() TO "authenticated"; GRANT ALL ON FUNCTION "public"."handle_new_user"() TO "service_role"; GRANT ALL ON FUNCTION "public"."scan_ticket"("_ticket_id" "uuid") TO "anon"; GRANT ALL ON FUNCTION "public"."scan_ticket"("_ticket_id" "uuid") TO "authenticated"; GRANT ALL ON FUNCTION "public"."scan_ticket"("_ticket_id" "uuid") TO "service_role"; GRANT ALL ON TABLE "public"."events_archived" TO "anon"; GRANT ALL ON TABLE "public"."events_archived" TO "authenticated"; GRANT ALL ON TABLE "public"."events_archived" TO "service_role"; GRANT ALL ON TABLE "public"."profiles" TO "anon"; GRANT ALL ON TABLE "public"."profiles" TO "authenticated"; GRANT ALL ON TABLE "public"."profiles" TO "service_role"; GRANT ALL ON TABLE "public"."sections" TO "anon"; GRANT ALL ON TABLE "public"."sections" TO "authenticated"; GRANT ALL ON TABLE "public"."sections" TO "service_role"; ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON SEQUENCES TO "postgres"; ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON SEQUENCES TO "anon"; ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON SEQUENCES TO "authenticated"; ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON SEQUENCES TO "service_role"; ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON FUNCTIONS TO "postgres"; ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON FUNCTIONS TO "anon"; ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON FUNCTIONS TO "authenticated"; ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON FUNCTIONS TO "service_role"; ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON TABLES TO "postgres"; ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON TABLES TO "anon"; ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON TABLES TO "authenticated"; ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON TABLES TO "service_role"; RESET ALL;