diff --git a/sql/postgres/migrations/001_initial.up.sql b/sql/postgres/migrations/001_initial.up.sql index 40d49ee..445fa4f 100644 --- a/sql/postgres/migrations/001_initial.up.sql +++ b/sql/postgres/migrations/001_initial.up.sql @@ -1,5 +1,5 @@ CREATE TABLE IF NOT EXISTS users( - id SERIAL PRIMARY KEY, + id INTEGER PRIMARY KEY GENERATED ALWAYS AS IDENTITY, username VARCHAR (255) UNIQUE NOT NULL, password TEXT NOT NULL, email TEXT NOT NULL, @@ -10,7 +10,7 @@ CREATE TABLE IF NOT EXISTS users( CREATE INDEX IF NOT EXISTS users_username_idx ON users(username); CREATE TABLE IF NOT EXISTS api_keys( - id SERIAL PRIMARY KEY, + id INTEGER PRIMARY KEY GENERATED ALWAYS AS IDENTITY, owner INTEGER REFERENCES users(id) NOT NULL, created_at TIMESTAMP NOT NULL, expires TIMESTAMP, @@ -24,7 +24,7 @@ CREATE TABLE IF NOT EXISTS systems( ); CREATE TABLE IF NOT EXISTS talkgroups( - id UUID PRIMARY KEY, + id INTEGER PRIMARY KEY GENERATED ALWAYS AS IDENTITY, system_id INT4 REFERENCES systems(id) NOT NULL, tgid INT4 NOT NULL, name TEXT, @@ -36,6 +36,7 @@ CREATE TABLE IF NOT EXISTS talkgroups( alert BOOLEAN NOT NULL DEFAULT 'true', alert_config JSONB, weight REAL NOT NULL DEFAULT 1.0, + learned BOOLEAN, UNIQUE (system_id, tgid) ); @@ -84,7 +85,8 @@ CREATE TABLE IF NOT EXISTS calls( tg_alpha_tag TEXT, tg_group TEXT, source INTEGER NOT NULL, - transcript TEXT + transcript TEXT, + FOREIGN KEY (system, talkgroup) REFERENCES talkgroups(system_id, tgid) ); CREATE INDEX IF NOT EXISTS calls_transcript_idx ON calls USING GIN (to_tsvector('english', transcript)); diff --git a/sql/postgres/migrations/002_tglearned.down.sql b/sql/postgres/migrations/002_tglearned.down.sql deleted file mode 100644 index 7355bf1..0000000 --- a/sql/postgres/migrations/002_tglearned.down.sql +++ /dev/null @@ -1,25 +0,0 @@ -ALTER TABLE calls DROP CONSTRAINT IF EXISTS calls_system_talkgroup_fkey; - -ALTER TABLE talkgroups DROP COLUMN IF EXISTS learned; - -ALTER TABLE talkgroups ALTER COLUMN id DROP IDENTITY IF EXISTS; -ALTER TABLE talkgroups ALTER COLUMN id SET DATA TYPE UUID USING (gen_random_uuid()); -DROP SEQUENCE IF EXISTS talkgroups_id_seq; - -CREATE OR REPLACE FUNCTION learn_talkgroup() -RETURNS TRIGGER AS $$ -BEGIN - IF NOT EXISTS ( - 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 - 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 - ) THEN - INSERT INTO talkgroups_learned(system_id, tgid, name, alpha_tag) VALUES( - NEW.system, NEW.talkgroup, NEW.tg_label, NEW.tg_alpha_tag - ) ON CONFLICT DO NOTHING; - END IF; - RETURN NEW; -END -$$ LANGUAGE plpgsql; - -CREATE OR REPLACE TRIGGER learn_tg AFTER INSERT ON calls FOR EACH ROW EXECUTE FUNCTION learn_talkgroup(); diff --git a/sql/postgres/migrations/002_tglearned.up.sql b/sql/postgres/migrations/002_tglearned.up.sql deleted file mode 100644 index 21f5cd2..0000000 --- a/sql/postgres/migrations/002_tglearned.up.sql +++ /dev/null @@ -1,24 +0,0 @@ -DROP TRIGGER IF EXISTS learn_tg ON calls; -DROP FUNCTION IF EXISTS learn_talkgroup(); - -CREATE SEQUENCE IF NOT EXISTS talkgroups_id_seq START WITH 1; -ALTER TABLE talkgroups ALTER COLUMN id SET DATA TYPE INTEGER USING (nextval('talkgroups_id_seq')); -ALTER TABLE talkgroups ALTER COLUMN id ADD GENERATED ALWAYS AS IDENTITY; -DROP SEQUENCE IF EXISTS talkgroups_id_seq; - -ALTER TABLE talkgroups ADD COLUMN IF NOT EXISTS learned BOOLEAN NOT NULL DEFAULT FALSE; - --- calls fkey constraint requires us to migrate all calls' talkgroup tuples to exist -INSERT INTO talkgroups (system_id, tgid, learned) -SELECT DISTINCT system_id, tgid, TRUE FROM talkgroups_learned ON CONFLICT DO NOTHING; - -INSERT INTO talkgroups (system_id, tgid, learned) -SELECT DISTINCT system, talkgroup, TRUE FROM calls ON CONFLICT DO NOTHING; - -INSERT INTO talkgroups_learned (system_id, tgid, name, tg_group, alpha_tag) -SELECT DISTINCT c.system, c.talkgroup, c.tg_label, c.tg_group, c.tg_alpha_tag -FROM calls c -JOIN talkgroups t ON (t.system_id = c.system AND t.tgid = c.talkgroup AND t.learned IS TRUE) -ON CONFLICT DO NOTHING; - -ALTER TABLE calls ADD CONSTRAINT calls_system_talkgroup_fkey FOREIGN KEY (system, talkgroup) REFERENCES talkgroups(system_id, tgid); diff --git a/sql/postgres/migrations/initial.sql b/sql/postgres/migrations/initial.sql deleted file mode 100644 index 445fa4f..0000000 --- a/sql/postgres/migrations/initial.sql +++ /dev/null @@ -1,121 +0,0 @@ -CREATE TABLE IF NOT EXISTS users( - id INTEGER PRIMARY KEY GENERATED ALWAYS AS IDENTITY, - username VARCHAR (255) UNIQUE NOT NULL, - password TEXT NOT NULL, - email TEXT NOT NULL, - is_admin BOOLEAN NOT NULL, - prefs JSONB -); - -CREATE INDEX IF NOT EXISTS users_username_idx ON users(username); - -CREATE TABLE IF NOT EXISTS api_keys( - id INTEGER PRIMARY KEY GENERATED ALWAYS AS IDENTITY, - owner INTEGER REFERENCES users(id) NOT NULL, - created_at TIMESTAMP NOT NULL, - expires TIMESTAMP, - disabled BOOLEAN, - api_key TEXT UNIQUE NOT NULL -); - -CREATE TABLE IF NOT EXISTS systems( - id INTEGER PRIMARY KEY, - name TEXT NOT NULL -); - -CREATE TABLE IF NOT EXISTS talkgroups( - id INTEGER PRIMARY KEY GENERATED ALWAYS AS IDENTITY, - system_id INT4 REFERENCES systems(id) NOT NULL, - tgid INT4 NOT NULL, - name TEXT, - alpha_tag TEXT, - tg_group TEXT, - frequency INTEGER, - metadata JSONB, - tags TEXT[] NOT NULL DEFAULT '{}', - alert BOOLEAN NOT NULL DEFAULT 'true', - alert_config JSONB, - weight REAL NOT NULL DEFAULT 1.0, - learned BOOLEAN, - UNIQUE (system_id, tgid) -); - -CREATE INDEX talkgroups_system_tgid_idx ON talkgroups (system_id, tgid); - -CREATE INDEX IF NOT EXISTS talkgroup_id_tags ON talkgroups USING GIN (tags); - -CREATE TABLE IF NOT EXISTS talkgroups_learned( - id INTEGER PRIMARY KEY GENERATED ALWAYS AS IDENTITY, - system_id INTEGER REFERENCES systems(id) NOT NULL, - tgid INTEGER NOT NULL, - name TEXT NOT NULL, - alpha_tag TEXT, - tg_group TEXT, - ignored BOOLEAN, - UNIQUE (system_id, tgid, name) -); - -CREATE TABLE IF NOT EXISTS alerts( - id INTEGER PRIMARY KEY GENERATED ALWAYS AS IDENTITY, - time TIMESTAMPTZ NOT NULL, - tgid INTEGER NOT NULL, - system_id INTEGER REFERENCES systems(id) NOT NULL, - weight REAL, - score REAL, - orig_score REAL, - notified BOOLEAN NOT NULL DEFAULT 'false', - metadata JSONB -); - -CREATE TABLE IF NOT EXISTS calls( - id UUID PRIMARY KEY, - submitter INTEGER REFERENCES api_keys(id) ON DELETE SET NULL, - system INTEGER NOT NULL, - talkgroup INTEGER NOT NULL, - call_date TIMESTAMPTZ NOT NULL, - audio_name TEXT, - audio_blob BYTEA, - duration INTEGER, - audio_type TEXT, - audio_url TEXT, - frequency INTEGER NOT NULL, - frequencies INTEGER[], - patches INTEGER[], - tg_label TEXT, - tg_alpha_tag TEXT, - tg_group TEXT, - source INTEGER NOT NULL, - transcript TEXT, - FOREIGN KEY (system, talkgroup) REFERENCES talkgroups(system_id, tgid) -); - -CREATE INDEX IF NOT EXISTS calls_transcript_idx ON calls USING GIN (to_tsvector('english', transcript)); -CREATE INDEX IF NOT EXISTS calls_call_date_tg_idx ON calls(system, talkgroup, call_date); - -CREATE TABLE IF NOT EXISTS settings( - name TEXT PRIMARY KEY, - updated_by INTEGER REFERENCES users(id), - value JSONB -); - -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 -); - -CREATE INDEX IF NOT EXISTS incidents_name_description_idx ON incidents USING GIN ( - (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) -);