Haystack/backend/schema.sql
John Costa 59bf884f5d refactor: changing notes to be a simple image description
Notes would generate too often and not be very useful. This is much
better.
2025-07-24 13:59:24 +01:00

182 lines
4.9 KiB
PL/PgSQL

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.locations (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
name TEXT NOT NULL,
address TEXT,
description TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT now()
);
CREATE TABLE haystack.image_locations (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
location_id UUID NOT NULL REFERENCES haystack.locations (id),
image_id UUID NOT NULL REFERENCES haystack.image (id),
created_at TIMESTAMP WITH TIME ZONE DEFAULT now()
);
CREATE TABLE haystack.user_locations (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
location_id UUID NOT NULL REFERENCES haystack.locations (id),
user_id UUID NOT NULL REFERENCES haystack.users (id),
created_at TIMESTAMP WITH TIME ZONE DEFAULT now()
);
CREATE TABLE haystack.contacts (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
-- It seems name and description are frequent. We could use table inheritance.
name TEXT NOT NULL,
description TEXT,
phone_number TEXT,
email TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT now()
);
CREATE TABLE haystack.user_contacts (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES haystack.users (id),
contact_id UUID NOT NULL REFERENCES haystack.contacts (id),
created_at TIMESTAMP WITH TIME ZONE DEFAULT now()
);
CREATE TABLE haystack.image_contacts (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
image_id UUID NOT NULL REFERENCES haystack.image (id),
contact_id UUID NOT NULL REFERENCES haystack.contacts (id),
created_at TIMESTAMP WITH TIME ZONE DEFAULT now()
);
CREATE TABLE haystack.events (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
-- It seems name and description are frequent. We could use table inheritance.
name TEXT NOT NULL,
description TEXT,
start_date_time TIMESTAMP,
end_date_time TIMESTAMP,
location_id UUID REFERENCES haystack.locations (id),
organizer_id UUID REFERENCES haystack.contacts (id),
created_at TIMESTAMP WITH TIME ZONE DEFAULT now()
);
CREATE TABLE haystack.image_events (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
event_id UUID NOT NULL REFERENCES haystack.events (id),
image_id UUID NOT NULL REFERENCES haystack.image (id),
created_at TIMESTAMP WITH TIME ZONE DEFAULT now()
);
CREATE TABLE haystack.user_events (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
event_id UUID NOT NULL REFERENCES haystack.events (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)
);
/* -----| 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 |----- */