DROP SCHEMA IF EXISTS haystack CASCADE; CREATE SCHEMA haystack; /* -----| Enums |----- */ CREATE TYPE haystack.progress AS ENUM('not-started','in-progress', 'complete'); /* -----| Schema tables |----- */ CREATE TABLE haystack.users ( id uuid PRIMARY KEY DEFAULT gen_random_uuid(), email TEXT NOT NULL ); CREATE TABLE haystack.image ( id uuid PRIMARY KEY DEFAULT gen_random_uuid(), image_name TEXT NOT NULL, description TEXT NOT NULL, image BYTEA NOT NULL ); CREATE TABLE haystack.user_images_to_process ( id uuid PRIMARY KEY DEFAULT gen_random_uuid(), status haystack.progress NOT NULL DEFAULT 'not-started', image_id uuid NOT NULL UNIQUE REFERENCES haystack.image (id), user_id uuid NOT NULL REFERENCES haystack.users (id) ); CREATE TABLE haystack.user_images ( id uuid PRIMARY KEY DEFAULT gen_random_uuid(), image_id uuid NOT NULL UNIQUE REFERENCES haystack.image (id), user_id uuid NOT NULL REFERENCES haystack.users (id), created_at TIMESTAMP WITH TIME ZONE DEFAULT now() ); CREATE TABLE haystack.logs ( log TEXT NOT NULL, image_id UUID NOT NULL REFERENCES haystack.image (id), created_at TIMESTAMP WITH TIME ZONE DEFAULT now() ); CREATE TABLE haystack.lists ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES haystack.users (id), name TEXT NOT NULL, description TEXT NOT NULL, created_at TIMESTAMP WITH TIME ZONE DEFAULT now() ); CREATE TABLE haystack.image_lists ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), image_id UUID NOT NULL REFERENCES haystack.image (id), list_id UUID NOT NULL REFERENCES haystack.lists (id) ); CREATE TABLE haystack.schemas ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), list_id UUID NOT NULL REFERENCES haystack.lists (id) ); CREATE TABLE haystack.schema_items ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), item TEXT NOT NULL, value TEXT NOT NULL, description TEXT NOT NULL, schema_id UUID NOT NULL REFERENCES haystack.schemas (id) ); CREATE TABLE haystack.image_schema_items ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), value TEXT, schema_item_id UUID NOT NULL REFERENCES haystack.schema_items (id), image_id UUID NOT NULL REFERENCES haystack.image (id) ); /* -----| Indexes |----- */ /* -----| Stored Procedures |----- */ CREATE OR REPLACE FUNCTION notify_new_image() RETURNS TRIGGER AS $$ BEGIN PERFORM pg_notify('new_image', NEW.id::texT); RETURN NEW; END $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION notify_new_processing_image_status() RETURNS TRIGGER AS $$ BEGIN PERFORM pg_notify('new_processing_image_status', NEW.id::text || NEW.status::text); RETURN NEW; END $$ LANGUAGE plpgsql; /* -----| Triggers |----- */ CREATE OR REPLACE TRIGGER on_new_image AFTER INSERT ON haystack.user_images_to_process FOR EACH ROW EXECUTE PROCEDURE notify_new_image(); CREATE OR REPLACE TRIGGER on_update_image_progress AFTER UPDATE OF status ON haystack.user_images_to_process FOR EACH ROW EXECUTE PROCEDURE notify_new_processing_image_status(); /* -----| Test Data |----- */