stillbox/sql/postgres/migrations/002_partition.up.sql
2024-11-29 23:24:43 -05:00

80 lines
2.8 KiB
PL/PgSQL

BEGIN;
ALTER TABLE calls RENAME TO calls_unpart;
CREATE TABLE calls (
id UUID,
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,
PRIMARY KEY (id, call_date),
FOREIGN KEY (system, talkgroup) REFERENCES talkgroups(system_id, tgid)
) PARTITION BY RANGE (call_date);
-- for our prod
create table calls_p_2024_07 partition of calls for values from ('2024-07-01') to ('2024-08-01');
create table calls_p_2024_08 partition of calls for values from ('2024-08-01') to ('2024-09-01');
create table calls_p_2024_09 partition of calls for values from ('2024-09-01') to ('2024-10-01');
create table calls_p_2024_10 partition of calls for values from ('2024-10-01') to ('2024-11-01');
create table calls_p_2024_11 partition of calls for values from ('2024-11-01') to ('2024-12-01');
insert into calls (id, submitter, system, talkgroup, call_date, audio_name, audio_blob, audio_url, frequency, frequencies, patches, tg_label, tg_alpha_tag, tg_group, source, transcript, duration) select id, submitter, system, talkgroup, call_date, audio_name, audio_blob, audio_url, frequency, frequencies, patches, tg_label, tg_alpha_tag, tg_group, source, transcript, duration from calls_unpart;
drop table calls_unpart cascade;
CREATE TABLE swept_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)
);
DROP TABLE IF EXISTS incidents_calls; -- DATA LOSS
CREATE TABLE IF NOT EXISTS incidents_calls(
incident_id UUID NOT NULL REFERENCES incidents(id) ON UPDATE CASCADE ON DELETE CASCADE,
call_id UUID NOT NULL,
calls_tbl_id UUID NULL,
swept_call_id UUID NULL REFERENCES swept_calls(id),
call_date TIMESTAMPTZ NULL,
notes JSONB,
FOREIGN KEY (calls_tbl_id, call_date) REFERENCES calls(id, call_date),
PRIMARY KEY (incident_id, call_id)
);
-- ALTER TABLE incidents_calls ADD COLUMN call_date TIMESTAMPTZ NOT NULL;
-- ALTER TABLE incidents_calls DROP CONSTRAINT incidents_calls_call_id_fkey;
-- ALTER TABLE incidents_calls ADD CONSTRAINT incidents_calls_call_id_call_date_fkey FOREIGN KEY (call_id, call_date) REFERENCES calls(id, call_date) ON UPDATE CASCADE;
COMMIT;