stillbox/sql/postgres/migrations/001_initial.up.sql

144 lines
3.6 KiB
MySQL
Raw Normal View History

2024-07-14 17:39:03 -04:00
CREATE TABLE IF NOT EXISTS users(
id SERIAL PRIMARY KEY,
username VARCHAR (255) UNIQUE NOT NULL,
2024-07-15 19:03:48 -04:00
password TEXT NOT NULL,
email TEXT NOT NULL,
2024-07-27 19:25:16 -04:00
is_admin BOOLEAN NOT NULL,
2024-07-15 19:03:48 -04:00
prefs JSONB
2024-07-14 17:39:03 -04:00
);
2024-07-16 19:31:30 -04:00
CREATE INDEX IF NOT EXISTS users_username_idx ON users(username);
2024-07-15 19:03:48 -04:00
2024-07-16 19:31:30 -04:00
CREATE TABLE IF NOT EXISTS api_keys(
2024-07-15 19:03:48 -04:00
id SERIAL PRIMARY KEY,
2024-07-27 19:25:16 -04:00
owner INTEGER REFERENCES users(id) NOT NULL,
2024-07-16 19:31:30 -04:00
created_at TIMESTAMP NOT NULL,
expires TIMESTAMP,
disabled BOOLEAN,
2024-08-03 00:05:02 -04:00
api_key TEXT UNIQUE NOT NULL
2024-07-15 19:03:48 -04:00
);
CREATE TABLE IF NOT EXISTS systems(
id INTEGER PRIMARY KEY,
name TEXT NOT NULL
);
2024-08-06 11:19:30 -04:00
CREATE OR REPLACE FUNCTION systg2id(_sys INTEGER, _tg INTEGER) RETURNS INT8 LANGUAGE plpgsql AS
$$
BEGIN
RETURN ((_sys::BIGINT << 32) | _tg);
END
$$;
CREATE OR REPLACE FUNCTION tgfromid(_id INT8) RETURNS INTEGER LANGUAGE plpgsql AS
$$
BEGIN
RETURN (_id & x'ffffffff'::BIGINT);
END
$$;
CREATE OR REPLACE FUNCTION sysfromid(_id INT8) RETURNS INTEGER LANGUAGE plpgsql AS
$$
BEGIN
RETURN (_id >> 32);
END
$$;
2024-07-15 19:03:48 -04:00
CREATE TABLE IF NOT EXISTS talkgroups(
2024-08-06 11:19:30 -04:00
id INT8 PRIMARY KEY,
system_id INT4 REFERENCES systems(id) NOT NULL GENERATED ALWAYS AS (id >> 32) STORED,
tgid INT4 NOT NULL GENERATED ALWAYS AS (id & x'ffffffff'::BIGINT) STORED,
2024-07-15 19:03:48 -04:00
name TEXT,
2024-08-23 14:28:47 -04:00
alpha_tag TEXT,
2024-07-28 01:08:08 -04:00
tg_group TEXT,
2024-07-15 19:03:48 -04:00
frequency INTEGER,
2024-07-16 19:31:30 -04:00
metadata JSONB,
2024-08-06 11:19:30 -04:00
tags TEXT[] NOT NULL DEFAULT '{}'
2024-07-15 19:03:48 -04:00
);
2024-07-28 23:07:04 -04:00
CREATE INDEX IF NOT EXISTS talkgroup_id_tags ON talkgroups USING GIN (tags);
2024-08-06 11:19:30 -04:00
2024-07-27 19:25:16 -04:00
CREATE TABLE IF NOT EXISTS talkgroups_learned(
id SERIAL PRIMARY KEY,
system_id INTEGER REFERENCES systems(id) NOT NULL,
tgid INTEGER NOT NULL,
2024-07-28 08:40:01 -04:00
name TEXT NOT NULL,
2024-08-23 14:28:47 -04:00
alpha_tag TEXT,
2024-07-28 01:08:08 -04:00
ignored BOOLEAN,
2024-07-28 08:40:01 -04:00
UNIQUE (system_id, tgid, name)
2024-07-27 19:25:16 -04:00
);
CREATE OR REPLACE FUNCTION learn_talkgroup()
RETURNS TRIGGER AS $$
BEGIN
2024-07-28 08:40:01 -04:00
IF NOT EXISTS (
2024-08-23 14:28:47 -04:00
SELECT tg.system_id, tg.tgid, tg.name, tg.alpha_tag FROM talkgroups tg WHERE tg.system_id = NEW.system AND tg.tgid = NEW.talkgroup
2024-07-28 08:40:01 -04:00
UNION
SELECT tgl.system_id, tgl.tgid, tgl.name, tgl.alpha_tag FROM talkgroups_learned tgl WHERE tgl.system_id = NEW.system AND tgl.tgid = NEW.talkgroup
2024-07-27 19:25:16 -04:00
) THEN
2024-09-02 19:15:58 -04:00
INSERT INTO talkgroups_learned(system_id, tgid, name, alpha_tag) VALUES(
2024-08-23 14:28:47 -04:00
NEW.system, NEW.talkgroup, NEW.tg_label, NEW.alpha_tag
2024-07-28 08:40:01 -04:00
) ON CONFLICT DO NOTHING;
2024-07-27 19:25:16 -04:00
END IF;
RETURN NEW;
END
$$ LANGUAGE plpgsql;
2024-07-15 19:03:48 -04:00
CREATE TABLE IF NOT EXISTS calls(
id UUID PRIMARY KEY,
2024-07-16 19:31:30 -04:00
submitter INTEGER REFERENCES api_keys(id) ON DELETE SET NULL,
2024-07-15 19:03:48 -04:00
system INTEGER NOT NULL,
talkgroup INTEGER NOT NULL,
2024-07-16 19:35:16 -04:00
call_date TIMESTAMP NOT NULL,
2024-07-15 19:03:48 -04:00
audio_name TEXT,
audio_blob BYTEA,
2024-08-11 13:46:43 -04:00
duration INTEGER,
2024-07-15 19:03:48 -04:00
audio_type TEXT,
audio_url TEXT,
2024-07-27 19:25:16 -04:00
frequency INTEGER NOT NULL,
frequencies INTEGER[],
patches INTEGER[],
2024-07-15 19:03:48 -04:00
tg_label TEXT,
2024-08-23 14:28:47 -04:00
tg_alpha_tag TEXT,
2024-07-27 19:25:16 -04:00
tg_group TEXT,
source INTEGER NOT NULL,
2024-07-16 19:31:30 -04:00
transcript TEXT
2024-07-15 19:03:48 -04:00
);
2024-07-16 19:31:30 -04:00
2024-07-27 19:25:16 -04:00
CREATE OR REPLACE TRIGGER learn_tg AFTER INSERT ON calls
FOR EACH ROW EXECUTE FUNCTION learn_talkgroup();
2024-07-16 19:31:30 -04:00
CREATE INDEX IF NOT EXISTS calls_transcript_idx ON calls USING GIN (to_tsvector('english', transcript));
2024-07-21 10:55:49 -04:00
CREATE INDEX IF NOT EXISTS calls_call_date_tg_idx ON calls(system, talkgroup, call_date);
2024-07-15 19:03:48 -04:00
CREATE TABLE IF NOT EXISTS settings(
name TEXT PRIMARY KEY,
updated_by INTEGER REFERENCES users(id),
value JSONB
);
2024-07-16 19:31:30 -04:00
CREATE TABLE IF NOT EXISTS incidents(
id UUID PRIMARY KEY,
name TEXT NOT NULL,
description TEXT,
start_time TIMESTAMP,
end_time TIMESTAMP,
location JSONB,
metadata JSONB
);
2024-07-21 10:46:51 -04:00
CREATE INDEX IF NOT EXISTS incidents_name_description_idx ON incidents USING GIN (
2024-07-16 19:31:30 -04:00
(to_tsvector('english', name) || to_tsvector('english', coalesce(description, ''))
)
);
CREATE TABLE IF NOT EXISTS incidents_calls(
incident_id UUID REFERENCES incidents(id) ON UPDATE CASCADE ON DELETE CASCADE,
call_id UUID REFERENCES calls(id) ON UPDATE CASCADE,
notes JSONB,
PRIMARY KEY (incident_id, call_id)
);