DROP SCHEMA IF EXISTS haystack CASCADE; CREATE SCHEMA haystack; /* -----| Enums |----- */ CREATE TYPE haystack.progress AS ENUM('not-started','in-progress'); /* -----| 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, 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) ); CREATE TABLE haystack.user_tags ( id uuid PRIMARY KEY DEFAULT gen_random_uuid(), tag VARCHAR(32) UNIQUE NOT NULL, user_id uuid NOT NULL REFERENCES haystack.users (id) ); CREATE TABLE haystack.image_tags ( id uuid PRIMARY KEY DEFAULT gen_random_uuid(), tag_id UUID NOT NULL REFERENCES haystack.user_tags (id), image_id UUID NOT NULL REFERENCES haystack.image (id) ); CREATE TABLE haystack.image_text ( id uuid PRIMARY KEY DEFAULT gen_random_uuid(), image_text TEXT NOT NULL, image_id UUID NOT NULL REFERENCES haystack.image (id) ); CREATE TABLE haystack.image_links ( id uuid PRIMARY KEY DEFAULT gen_random_uuid(), link TEXT NOT NULL, image_id UUID NOT NULL REFERENCES haystack.image (id) ); CREATE TABLE haystack.locations ( id uuid PRIMARY KEY DEFAULT gen_random_uuid(), name TEXT NOT NULL, address TEXT, description TEXT ); 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) ); 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) ); 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 ); 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) ); 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) ); 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) ); 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) ); 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) ); CREATE TABLE haystack.notes ( 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, content TEXT NOT NULL ); CREATE TABLE haystack.image_notes ( id uuid PRIMARY KEY DEFAULT gen_random_uuid(), image_id UUID NOT NULL REFERENCES haystack.image (id), note_id UUID NOT NULL REFERENCES haystack.notes (id) ); CREATE TABLE haystack.user_notes ( id uuid PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES haystack.users (id), note_id UUID NOT NULL REFERENCES haystack.notes (id) ); /* -----| Indexes |----- */ CREATE INDEX user_tags_index ON haystack.user_tags(tag); /* -----| 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.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 |----- */ -- Insert a user INSERT INTO haystack.users (id, email) VALUES ('1db09f34-b155-4bf2-b606-dda25365fc89', 'me@email.com'); -- Insert images INSERT INTO haystack.image (id, image_name, image) VALUES ('3bd3fa04-e4b4-4ffb-b282-d573a092eb71', 'Sample Image 1', 'sample_image_1_bytes'), ('f4560a78-d5d3-433e-8d90-b75c66e25423', 'Sample Image 2', 'sample_image_2_bytes'); -- Insert user images to process INSERT INTO haystack.user_images_to_process (id, image_id, user_id) VALUES ('abe3679c-e787-4670-b5da-570453938f18', '3bd3fa04-e4b4-4ffb-b282-d573a092eb71', '1db09f34-b155-4bf2-b606-dda25365fc89'), ('8f3727e8-03fa-49bf-b0fe-ba8762df0902', 'f4560a78-d5d3-433e-8d90-b75c66e25423', '1db09f34-b155-4bf2-b606-dda25365fc89'); -- Insert user images INSERT INTO haystack.user_images (id, image_id, user_id) VALUES ('28ade3a5-30c0-4f0a-93ff-5d062ba5c253', '3bd3fa04-e4b4-4ffb-b282-d573a092eb71', '1db09f34-b155-4bf2-b606-dda25365fc89'), ('c9425f01-a496-4c0a-919e-54b58c8ba600', 'f4560a78-d5d3-433e-8d90-b75c66e25423', '1db09f34-b155-4bf2-b606-dda25365fc89'); -- Insert user tags INSERT INTO haystack.user_tags (id, tag, user_id) VALUES ('118c9491-a1ea-4930-88ee-33edfbc61cd3', 'vacation', '1db09f34-b155-4bf2-b606-dda25365fc89'), ('c3e8c00a-4af6-45c6-acc3-53aa7ce2024a', 'family', '1db09f34-b155-4bf2-b606-dda25365fc89'); -- Insert image tags INSERT INTO haystack.image_tags (id, tag_id, image_id) VALUES ('38ec5481-7b09-4e50-98b8-a85bbd5f6c6e', '118c9491-a1ea-4930-88ee-33edfbc61cd3', '3bd3fa04-e4b4-4ffb-b282-d573a092eb71'), ('9d64f58e-1d61-4c97-ae8b-a38bc3519fe1', 'c3e8c00a-4af6-45c6-acc3-53aa7ce2024a', 'f4560a78-d5d3-433e-8d90-b75c66e25423'); -- Insert image text INSERT INTO haystack.image_text (id, image_text, image_id) VALUES ('fdd7a9f4-2a9a-494e-89d2-a63df8e45d62', 'Sample text for image 1', '3bd3fa04-e4b4-4ffb-b282-d573a092eb71'), ('95516f15-575c-485b-92ab-22eb18a306c1', 'Sample text for image 2', 'f4560a78-d5d3-433e-8d90-b75c66e25423'); -- Insert image links INSERT INTO haystack.image_links (id, link, image_id) VALUES ('bbcc284f-c1f6-47ac-8d54-65b7729f03be', 'http://example.com/image1', '3bd3fa04-e4b4-4ffb-b282-d573a092eb71'), ('7391b2d1-6141-4195-8a4c-9c8ba4491b5a', 'http://example.com/image2', 'f4560a78-d5d3-433e-8d90-b75c66e25423'); -- Insert locations INSERT INTO haystack.locations (id, name, address, description) VALUES ('5ac6f116-c21a-408b-9d2b-e8227a9a8503', 'Sample Location 1', '123 Sample St', 'A sample location'), ('cd4b1815-5019-406d-9f1d-e9e5ac34c5f1', 'Sample Location 2', '456 Sample Ave', 'Another sample location'); -- Insert image locations INSERT INTO haystack.image_locations (id, location_id, image_id) VALUES ('0e0c5cc2-b5b3-4b26-9d9c-2517b9358eb3', '5ac6f116-c21a-408b-9d2b-e8227a9a8503', '3bd3fa04-e4b4-4ffb-b282-d573a092eb71'), ('98facc74-cfc0-41cd-87e1-5e3822ae3407', 'cd4b1815-5019-406d-9f1d-e9e5ac34c5f1', 'f4560a78-d5d3-433e-8d90-b75c66e25423'); -- Insert user locations INSERT INTO haystack.user_locations (id, location_id, user_id) VALUES ('1427ca1c-293f-4fab-b813-2acf145715f5', '5ac6f116-c21a-408b-9d2b-e8227a9a8503', '1db09f34-b155-4bf2-b606-dda25365fc89'), ('343f9321-f63d-4248-aaab-3a1264d9cb5e', 'cd4b1815-5019-406d-9f1d-e9e5ac34c5f1', '1db09f34-b155-4bf2-b606-dda25365fc89'); -- Insert contacts INSERT INTO haystack.contacts (id, name, description, phone_number, email) VALUES ('943be2ab-4db4-4e4e-bd1c-b78ad96df0d1', 'Contact 1', 'Sample contact description', '123-456-7890', 'contact1@example.com'), ('09e2bf18-09b7-4553-971e-45136bd5b12f', 'Contact 2', 'Another sample contact description', '098-765-4321', 'contact2@example.com'); -- Insert user contacts INSERT INTO haystack.user_contacts (id, user_id, contact_id) VALUES ('d74125e4-cbe4-4b83-8432-e0a3206af91c', '1db09f34-b155-4bf2-b606-dda25365fc89', '943be2ab-4db4-4e4e-bd1c-b78ad96df0d1'), ('46e8cbd4-46a6-4499-9575-d3aad003fd1c', '1db09f34-b155-4bf2-b606-dda25365fc89', '09e2bf18-09b7-4553-971e-45136bd5b12f'); -- Insert image contacts INSERT INTO haystack.image_contacts (id, image_id, contact_id) VALUES ('db075381-e89b-4582-800e-07561f9139e8', '3bd3fa04-e4b4-4ffb-b282-d573a092eb71', '943be2ab-4db4-4e4e-bd1c-b78ad96df0d1'), ('7384970d-3d3c-4e29-b158-edf200c53169', 'f4560a78-d5d3-433e-8d90-b75c66e25423', '09e2bf18-09b7-4553-971e-45136bd5b12f'); -- Insert events INSERT INTO haystack.events (id, name, description, start_date_time, end_date_time, location_id, organizer_id) VALUES ('24a9dcbc-f8dc-4fca-835b-7ea57850d0b7', 'Sample Event 1', 'A sample event description', '2023-01-01 10:00:00', '2023-01-01 12:00:00', '5ac6f116-c21a-408b-9d2b-e8227a9a8503', '943be2ab-4db4-4e4e-bd1c-b78ad96df0d1'), ('9cb6b0ae-3b02-4343-9858-5a07dd248562', 'Sample Event 2', 'Another sample event description', '2023-02-01 14:00:00', '2023-02-01 16:00:00', 'cd4b1815-5019-406d-9f1d-e9e5ac34c5f1', '09e2bf18-09b7-4553-971e-45136bd5b12f'); -- Insert image events INSERT INTO haystack.image_events (id, event_id, image_id) VALUES ('5268a005-b3eb-4a30-8823-c8e9666507bb', '24a9dcbc-f8dc-4fca-835b-7ea57850d0b7', '3bd3fa04-e4b4-4ffb-b282-d573a092eb71'), ('9d6d4d26-c2a2-427f-92ed-34dc8c2d3e5f', '9cb6b0ae-3b02-4343-9858-5a07dd248562', 'f4560a78-d5d3-433e-8d90-b75c66e25423'); -- Insert user events INSERT INTO haystack.user_events (id, event_id, user_id) VALUES ('16d815e4-6387-4fe9-b31d-5baff0567345', '24a9dcbc-f8dc-4fca-835b-7ea57850d0b7', '1db09f34-b155-4bf2-b606-dda25365fc89'), ('43078366-d265-4ff9-9210-e11680bd6bcd', '9cb6b0ae-3b02-4343-9858-5a07dd248562', '1db09f34-b155-4bf2-b606-dda25365fc89'); -- Insert notes INSERT INTO haystack.notes (id, name, description, content) VALUES ('6524f6b9-c659-409e-b2a0-abd3c3f5b5bb', 'Sample Note 1', 'A sample note description', 'This is the content of the sample note 1'), ('a274b9b3-024f-457d-b4a0-d4535c2cca54', 'Sample Note 2', 'Another sample note description', 'This is the content of the sample note 2'); -- Insert image notes INSERT INTO haystack.image_notes (id, image_id, note_id) VALUES ('6062fceb-7b3f-41fb-8509-489218968204', '3bd3fa04-e4b4-4ffb-b282-d573a092eb71', '6524f6b9-c659-409e-b2a0-abd3c3f5b5bb'), ('956dd3f6-4513-4cbc-9a5e-03dbec769402', 'f4560a78-d5d3-433e-8d90-b75c66e25423', 'a274b9b3-024f-457d-b4a0-d4535c2cca54'); -- Insert user notes INSERT INTO haystack.user_notes (id, user_id, note_id) VALUES ('e3fa7a74-acbf-4aa9-930b-f10bd8a6ced5', '1db09f34-b155-4bf2-b606-dda25365fc89', '6524f6b9-c659-409e-b2a0-abd3c3f5b5bb'), ('ebaef76b-3b78-491c-93f7-19510080284d', '1db09f34-b155-4bf2-b606-dda25365fc89', 'a274b9b3-024f-457d-b4a0-d4535c2cca54');