mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 09:57:09 +00:00
Add database upgrade file 08
This commit is contained in:
75
etc/db/upgrades/upgrade08-81d9ea19→74b3de5c.sql
Normal file
75
etc/db/upgrades/upgrade08-81d9ea19→74b3de5c.sql
Normal file
@@ -0,0 +1,75 @@
|
||||
-- Upgrade the database from commit 81d9ea19 to 74b3de5c.
|
||||
--
|
||||
-- This upgrade affects the `public` schema only.
|
||||
--
|
||||
-- It creates a new table, `queue_items`, for storing
|
||||
-- requests and responses related to inter-API communication.
|
||||
-- At the moment this means Equinor's ASAQC API, but it
|
||||
-- should be applicable to others as well if the need
|
||||
-- arises.
|
||||
--
|
||||
-- As well as the table, it adds:
|
||||
--
|
||||
-- * `queue_item_status`, an ENUM type.
|
||||
-- * `update_timestamp`, a trigger function.
|
||||
-- * Two triggers on `queue_items`.
|
||||
--
|
||||
-- To apply, run as the dougal user:
|
||||
--
|
||||
-- psql < $THIS_FILE
|
||||
--
|
||||
-- NOTE: It will fail harmlessly if applied twice.
|
||||
|
||||
|
||||
-- Queues are global, not per project,
|
||||
-- so they go in the `public` schema.
|
||||
|
||||
|
||||
CREATE TYPE queue_item_status
|
||||
AS ENUM (
|
||||
'queued',
|
||||
'cancelled',
|
||||
'failed',
|
||||
'sent'
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS queue_items (
|
||||
item_id serial NOT NULL PRIMARY KEY,
|
||||
-- One day we may want multiple queues, in that case we will
|
||||
-- have a queue_id and a relation of queue definitions.
|
||||
-- But not right now.
|
||||
-- queue_id integer NOT NULL REFERENCES queues (queue_id),
|
||||
status queue_item_status NOT NULL DEFAULT 'queued',
|
||||
payload jsonb NOT NULL,
|
||||
results jsonb NOT NULL DEFAULT '{}'::jsonb,
|
||||
created_on timestamptz NOT NULL DEFAULT current_timestamp,
|
||||
updated_on timestamptz NOT NULL DEFAULT current_timestamp,
|
||||
not_before timestamptz NOT NULL DEFAULT '1970-01-01T00:00:00Z',
|
||||
parent_id integer NULL REFERENCES queue_items (item_id)
|
||||
);
|
||||
|
||||
-- Sets `updated_on` to current_timestamp unless an explicit
|
||||
-- timestamp is part of the update.
|
||||
--
|
||||
-- This function can be reused with any table that has (or could have)
|
||||
-- an `updated_on` column of time timestamptz.
|
||||
CREATE OR REPLACE FUNCTION update_timestamp () RETURNS trigger AS
|
||||
$$
|
||||
BEGIN
|
||||
IF NEW.updated_on IS NOT NULL THEN
|
||||
NEW.updated_on := current_timestamp;
|
||||
END IF;
|
||||
RETURN NEW;
|
||||
EXCEPTION
|
||||
WHEN undefined_column THEN RETURN NEW;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER queue_items_tg0
|
||||
BEFORE INSERT OR UPDATE ON public.queue_items
|
||||
FOR EACH ROW EXECUTE FUNCTION public.update_timestamp();
|
||||
|
||||
CREATE TRIGGER queue_items_tg1
|
||||
AFTER INSERT OR DELETE OR UPDATE ON public.queue_items
|
||||
FOR EACH ROW EXECUTE FUNCTION public.notify('queue_items');
|
||||
Reference in New Issue
Block a user