This allows a single table to be used to process images, meaning if anything happens to the system we can always return to polling the database and process these images individually. Because of this we also want an `image` table to contain the actual binary data for the image, so we aren't selecting and writing it each time, as it is potentially a bottleneck.
70 lines
1.8 KiB
PL/PgSQL
70 lines
1.8 KiB
PL/PgSQL
DROP DATABASE IF EXISTS haystack_db;
|
|
CREATE DATABASE haystack_db;
|
|
|
|
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.image_tags (
|
|
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
tag TEXT NOT NULL,
|
|
image_id UUID NOT NULL REFERENCES haystack.user_images (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.user_images (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.user_images (id)
|
|
);
|
|
|
|
/* -----| 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');
|