121 lines
3.3 KiB
PL/PgSQL
121 lines
3.3 KiB
PL/PgSQL
DROP SCHEMA IF EXISTS haystack CASCADE;
|
|
|
|
CREATE SCHEMA haystack;
|
|
|
|
/* -----| Schema tables |----- */
|
|
|
|
CREATE TABLE haystack.users (
|
|
id uuid PRIMARY KEY DEFAULT gen_random_uuid()
|
|
);
|
|
|
|
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(),
|
|
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.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)
|
|
);
|
|
|
|
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)
|
|
);
|
|
|
|
/* -----| 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;
|
|
|
|
/* -----| Triggers |----- */
|
|
|
|
CREATE OR REPLACE TRIGGER on_new_image AFTER INSERT
|
|
ON haystack.user_images_to_process
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE notify_new_image();
|
|
|
|
/* -----| Test Data |----- */
|
|
|
|
INSERT INTO haystack.users VALUES ('fcc22dbb-7792-4595-be8e-d0439e13990a');
|