From d6d2da3e04f0e3bde512a925c78dbd42fc9a1cc1 Mon Sep 17 00:00:00 2001 From: Daniel Ponte Date: Tue, 16 Jul 2024 19:31:30 -0400 Subject: [PATCH] Schema --- pkg/gordio/database/calls.sql.go | 99 ++++++++++++++++++++++ pkg/gordio/database/models.go | 42 ++++++--- pkg/gordio/database/users.sql.go | 40 +++++++++ sql/postgres/migrations/001_initial.up.sql | 42 +++++++-- sql/postgres/queries/calls.sql | 5 +- sql/postgres/queries/users.sql | 13 +++ 6 files changed, 224 insertions(+), 17 deletions(-) create mode 100644 pkg/gordio/database/calls.sql.go diff --git a/pkg/gordio/database/calls.sql.go b/pkg/gordio/database/calls.sql.go new file mode 100644 index 0000000..b7489f5 --- /dev/null +++ b/pkg/gordio/database/calls.sql.go @@ -0,0 +1,99 @@ +// Code generated by sqlc. DO NOT EDIT. +// versions: +// sqlc v1.26.0 +// source: calls.sql + +package database + +import ( + "context" + + "github.com/jackc/pgx/v5/pgtype" +) + +const addCall = `-- name: AddCall :one +INSERT INTO calls ( + id, + submitter, + system, + talkgroup, + date, + audio_name, + audio_blob, + audio_type, + audio_url, + frequency, + frequencies, + patches, + tg_label, + source + ) VALUES (gen_random_uuid(), $1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13) +RETURNING id, submitter, system, talkgroup, date, audio_name, audio_blob, audio_type, audio_url, frequency, frequencies, patches, tg_label, source, transcript +` + +type AddCallParams struct { + Submitter pgtype.Int4 + System int32 + Talkgroup int32 + Date pgtype.Timestamp + AudioName pgtype.Text + AudioBlob []byte + AudioType pgtype.Text + AudioUrl pgtype.Text + Frequency pgtype.Int4 + Frequencies []byte + Patches []byte + TgLabel pgtype.Text + Source pgtype.Text +} + +func (q *Queries) AddCall(ctx context.Context, arg AddCallParams) (Call, error) { + row := q.db.QueryRow(ctx, addCall, + arg.Submitter, + arg.System, + arg.Talkgroup, + arg.Date, + arg.AudioName, + arg.AudioBlob, + arg.AudioType, + arg.AudioUrl, + arg.Frequency, + arg.Frequencies, + arg.Patches, + arg.TgLabel, + arg.Source, + ) + var i Call + err := row.Scan( + &i.ID, + &i.Submitter, + &i.System, + &i.Talkgroup, + &i.Date, + &i.AudioName, + &i.AudioBlob, + &i.AudioType, + &i.AudioUrl, + &i.Frequency, + &i.Frequencies, + &i.Patches, + &i.TgLabel, + &i.Source, + &i.Transcript, + ) + return i, err +} + +const updateCallTranscript = `-- name: UpdateCallTranscript :exec +UPDATE calls SET transcript = $2 WHERE id = $1 +` + +type UpdateCallTranscriptParams struct { + ID pgtype.UUID + Transcript pgtype.Text +} + +func (q *Queries) UpdateCallTranscript(ctx context.Context, arg UpdateCallTranscriptParams) error { + _, err := q.db.Exec(ctx, updateCallTranscript, arg.ID, arg.Transcript) + return err +} diff --git a/pkg/gordio/database/models.go b/pkg/gordio/database/models.go index 724651d..1ef2735 100644 --- a/pkg/gordio/database/models.go +++ b/pkg/gordio/database/models.go @@ -8,15 +8,18 @@ import ( "github.com/jackc/pgx/v5/pgtype" ) -type Apikey struct { - ID int32 - Owner pgtype.Int4 - ApiKey string +type ApiKey struct { + ID int32 + Owner pgtype.Int4 + CreatedAt pgtype.Timestamp + Expires pgtype.Timestamp + Disabled pgtype.Bool + ApiKey pgtype.UUID } type Call struct { ID pgtype.UUID - Submitter int32 + Submitter pgtype.Int4 System int32 Talkgroup int32 Date pgtype.Timestamp @@ -29,6 +32,23 @@ type Call struct { Patches []byte TgLabel pgtype.Text Source pgtype.Text + Transcript pgtype.Text +} + +type Incident struct { + ID pgtype.UUID + Name string + Description pgtype.Text + StartTime pgtype.Timestamp + EndTime pgtype.Timestamp + Location []byte + Metadata []byte +} + +type IncidentsCall struct { + IncidentID pgtype.UUID + CallID pgtype.UUID + Notes []byte } type Setting struct { @@ -43,11 +63,13 @@ type System struct { } type Talkgroup struct { - ID int32 - System int32 - Name pgtype.Text - Frequency pgtype.Int4 - GroupID pgtype.Int4 + ID int32 + System int32 + Name pgtype.Text + Frequency pgtype.Int4 + GroupID pgtype.Int4 + AutoCreated pgtype.Bool + Metadata []byte } type User struct { diff --git a/pkg/gordio/database/users.sql.go b/pkg/gordio/database/users.sql.go index 1cb4e86..5c8b0ad 100644 --- a/pkg/gordio/database/users.sql.go +++ b/pkg/gordio/database/users.sql.go @@ -11,6 +11,37 @@ import ( "github.com/jackc/pgx/v5/pgtype" ) +const createAPIKey = `-- name: CreateAPIKey :one +INSERT INTO api_keys( + owner, + created_at, + expires, + disabled, + api_key + ) VALUES ($1, NOW(), $2, $3, gen_random_uuid()) +RETURNING id, owner, created_at, expires, disabled, api_key +` + +type CreateAPIKeyParams struct { + Owner pgtype.Int4 + Expires pgtype.Timestamp + Disabled pgtype.Bool +} + +func (q *Queries) CreateAPIKey(ctx context.Context, arg CreateAPIKeyParams) (ApiKey, error) { + row := q.db.QueryRow(ctx, createAPIKey, arg.Owner, arg.Expires, arg.Disabled) + var i ApiKey + err := row.Scan( + &i.ID, + &i.Owner, + &i.CreatedAt, + &i.Expires, + &i.Disabled, + &i.ApiKey, + ) + return i, err +} + const createUser = `-- name: CreateUser :one INSERT INTO users ( username, @@ -47,6 +78,15 @@ func (q *Queries) CreateUser(ctx context.Context, arg CreateUserParams) (User, e return i, err } +const deleteAPIKey = `-- name: DeleteAPIKey :exec +DELETE FROM api_keys WHERE api_key = $1 +` + +func (q *Queries) DeleteAPIKey(ctx context.Context, apiKey pgtype.UUID) error { + _, err := q.db.Exec(ctx, deleteAPIKey, apiKey) + return err +} + const deleteUser = `-- name: DeleteUser :exec DELETE FROM users WHERE username = $1 ` diff --git a/sql/postgres/migrations/001_initial.up.sql b/sql/postgres/migrations/001_initial.up.sql index 7863f45..2ac6a97 100644 --- a/sql/postgres/migrations/001_initial.up.sql +++ b/sql/postgres/migrations/001_initial.up.sql @@ -7,12 +7,15 @@ CREATE TABLE IF NOT EXISTS users( prefs JSONB ); -CREATE INDEX IF NOT EXISTS users_username ON users(username); +CREATE INDEX IF NOT EXISTS users_username_idx ON users(username); -CREATE TABLE IF NOT EXISTS apikeys( +CREATE TABLE IF NOT EXISTS api_keys( id SERIAL PRIMARY KEY, owner INTEGER REFERENCES users(id), - api_key TEXT UNIQUE NOT NULL + created_at TIMESTAMP NOT NULL, + expires TIMESTAMP, + disabled BOOLEAN, + api_key UUID UNIQUE NOT NULL ); CREATE TABLE IF NOT EXISTS systems( @@ -26,12 +29,14 @@ CREATE TABLE IF NOT EXISTS talkgroups( name TEXT, frequency INTEGER, group_id INTEGER, + auto_created BOOLEAN, + metadata JSONB, PRIMARY KEY (tgid, system) ); CREATE TABLE IF NOT EXISTS calls( id UUID PRIMARY KEY, - submitter INTEGER REFERENCES apikeys(id) NOT NULL, + submitter INTEGER REFERENCES api_keys(id) ON DELETE SET NULL, system INTEGER NOT NULL, talkgroup INTEGER NOT NULL, date TIMESTAMP NOT NULL, @@ -44,13 +49,38 @@ CREATE TABLE IF NOT EXISTS calls( patches JSONB, tg_label TEXT, source TEXT, - FOREIGN KEY (system, talkgroup) REFERENCES talkgroups(system, id) + transcript TEXT ); -CREATE INDEX IF NOT EXISTS calls_date_tg ON calls(talkgroup, date); + +CREATE INDEX IF NOT EXISTS calls_transcript_idx ON calls USING GIN (to_tsvector('english', transcript)); +CREATE INDEX IF NOT EXISTS calls_date_tg_idx ON calls(talkgroup, 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 calls_name_description_idx ON calls 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, + -- CONSTRAINT incident_call_pkey PRIMARY KEY (incident_id, call_id) + PRIMARY KEY (incident_id, call_id) +); diff --git a/sql/postgres/queries/calls.sql b/sql/postgres/queries/calls.sql index 0e3017b..38f7fa1 100644 --- a/sql/postgres/queries/calls.sql +++ b/sql/postgres/queries/calls.sql @@ -9,10 +9,13 @@ INSERT INTO calls ( audio_blob, audio_type, audio_url, - frequency_integer, + frequency, frequencies, patches, tg_label, source ) VALUES (gen_random_uuid(), $1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13) RETURNING *; + +-- name: UpdateCallTranscript :exec +UPDATE calls SET transcript = $2 WHERE id = $1; diff --git a/sql/postgres/queries/users.sql b/sql/postgres/queries/users.sql index dafd9ad..625800e 100644 --- a/sql/postgres/queries/users.sql +++ b/sql/postgres/queries/users.sql @@ -27,3 +27,16 @@ DELETE FROM users WHERE username = $1; -- name: UpdatePassword :exec UPDATE users SET password = $2 WHERE username = $1; + +-- name: CreateAPIKey :one +INSERT INTO api_keys( + owner, + created_at, + expires, + disabled, + api_key + ) VALUES ($1, NOW(), $2, $3, gen_random_uuid()) +RETURNING *; + +-- name: DeleteAPIKey :exec +DELETE FROM api_keys WHERE api_key = $1;