From e38ebe680204b3cc1d3d9b992d9a74e56f99ccc9 Mon Sep 17 00:00:00 2001 From: Daniel Ponte Date: Thu, 14 Nov 2024 08:37:19 -0500 Subject: [PATCH] reid first stab --- pkg/alerting/alerting.go | 6 +- pkg/alerting/stats.go | 2 +- pkg/database/models.go | 2 +- pkg/database/querier.go | 8 +- pkg/database/talkgroups.manual.sql.go | 124 ++++++++++++++ pkg/database/talkgroups.sql.go | 131 ++------------- pkg/rest/talkgroups.go | 1 - pkg/talkgroups/cache.go | 18 +- pkg/talkgroups/import.go | 4 +- pkg/talkgroups/talkgroup.go | 19 +-- sql/postgres/migrations/002_reid.down.sql | 9 + sql/postgres/migrations/002_reid.up.sql | 7 + sql/postgres/migrations/flattened_initial.sql | 157 ++++++++++++++++++ sql/postgres/queries/talkgroups.sql | 33 +--- sql/sqlc.yaml | 4 + 15 files changed, 348 insertions(+), 177 deletions(-) create mode 100644 pkg/database/talkgroups.manual.sql.go create mode 100644 sql/postgres/migrations/002_reid.down.sql create mode 100644 sql/postgres/migrations/002_reid.up.sql create mode 100644 sql/postgres/migrations/flattened_initial.sql diff --git a/pkg/alerting/alerting.go b/pkg/alerting/alerting.go index db4c1ff..ee3ec5f 100644 --- a/pkg/alerting/alerting.go +++ b/pkg/alerting/alerting.go @@ -229,10 +229,10 @@ func (as *alerter) scoredTGs() []talkgroups.ID { } // packedScoredTGs gets a list of packed TGIDs. -func (as *alerter) packedScoredTGs() []int64 { - tgs := make([]int64, 0, len(as.scores)) +func (as *alerter) scoredTGsTuple() []database.TalkgroupT { + tgs := make([]database.TalkgroupT, 0, len(as.scores)) for _, s := range as.scores { - tgs = append(tgs, s.ID.Pack()) + tgs = append(tgs, s.ID.Tuple()) } return tgs diff --git a/pkg/alerting/stats.go b/pkg/alerting/stats.go index b724c01..6ba16dd 100644 --- a/pkg/alerting/stats.go +++ b/pkg/alerting/stats.go @@ -40,7 +40,7 @@ func (as *alerter) tgStatsHandler(w http.ResponseWriter, r *http.Request) { ctx := r.Context() db := database.FromCtx(ctx) - tgs, err := db.GetTalkgroupsWithLearnedByPackedIDs(ctx, as.packedScoredTGs()) + tgs, err := db.GetTalkgroupsWithLearnedByPackedIDs(ctx, as.scoredTGsTuple()) if err != nil { log.Error().Err(err).Msg("stats TG get failed") http.Error(w, err.Error(), http.StatusInternalServerError) diff --git a/pkg/database/models.go b/pkg/database/models.go index 9da62d6..8bb2b05 100644 --- a/pkg/database/models.go +++ b/pkg/database/models.go @@ -83,7 +83,7 @@ type System struct { } type Talkgroup struct { - ID int64 `json:"id"` + ID uuid.UUID `json:"id"` SystemID int32 `json:"system_id"` Tgid int32 `json:"tgid"` Name *string `json:"name"` diff --git a/pkg/database/querier.go b/pkg/database/querier.go index 6a814c3..8d91e22 100644 --- a/pkg/database/querier.go +++ b/pkg/database/querier.go @@ -14,7 +14,7 @@ import ( type Querier interface { AddAlert(ctx context.Context, arg AddAlertParams) error AddCall(ctx context.Context, arg AddCallParams) error - BulkSetTalkgroupTags(ctx context.Context, iD int64, tags []string) error + BulkSetTalkgroupTags(ctx context.Context, iD uuid.UUID, tags []string) error CreateAPIKey(ctx context.Context, owner int, expires pgtype.Timestamp, disabled *bool) (ApiKey, error) CreateUser(ctx context.Context, arg CreateUserParams) (User, error) DeleteAPIKey(ctx context.Context, apiKey string) error @@ -22,15 +22,13 @@ type Querier interface { GetAPIKey(ctx context.Context, apiKey string) (ApiKey, error) GetDatabaseSize(ctx context.Context) (string, error) GetSystemName(ctx context.Context, systemID int) (string, error) - GetTalkgroup(ctx context.Context, systemID int, tgid int) (GetTalkgroupRow, error) + GetTalkgroup(ctx context.Context, systemID int32, tgid int32) (GetTalkgroupRow, error) GetTalkgroupIDsByTags(ctx context.Context, anytags []string, alltags []string, nottags []string) ([]GetTalkgroupIDsByTagsRow, error) GetTalkgroupTags(ctx context.Context, sys int, tg int) ([]string, error) - GetTalkgroupWithLearned(ctx context.Context, systemID int, tgid int) (GetTalkgroupWithLearnedRow, error) - GetTalkgroupsByPackedIDs(ctx context.Context, dollar_1 []int64) ([]GetTalkgroupsByPackedIDsRow, error) + GetTalkgroupWithLearned(ctx context.Context, systemID int32, tgid int32) (GetTalkgroupWithLearnedRow, error) GetTalkgroupsWithAllTags(ctx context.Context, tags []string) ([]GetTalkgroupsWithAllTagsRow, error) GetTalkgroupsWithAnyTags(ctx context.Context, tags []string) ([]GetTalkgroupsWithAnyTagsRow, error) GetTalkgroupsWithLearned(ctx context.Context) ([]GetTalkgroupsWithLearnedRow, error) - GetTalkgroupsWithLearnedByPackedIDs(ctx context.Context, dollar_1 []int64) ([]GetTalkgroupsWithLearnedByPackedIDsRow, error) GetTalkgroupsWithLearnedBySystem(ctx context.Context, system int32) ([]GetTalkgroupsWithLearnedBySystemRow, error) GetUserByID(ctx context.Context, id int32) (User, error) GetUserByUID(ctx context.Context, id int32) (User, error) diff --git a/pkg/database/talkgroups.manual.sql.go b/pkg/database/talkgroups.manual.sql.go new file mode 100644 index 0000000..c141e23 --- /dev/null +++ b/pkg/database/talkgroups.manual.sql.go @@ -0,0 +1,124 @@ +package database + +import ( + "context" + "database/sql/driver" +) + +type TalkgroupT struct { + System uint32 `json:"sys"` + Talkgroup uint32 `json:"tg"` +} + +func (t TalkgroupT) Value() (driver.Value, error) { + return [2]uint32{t.System, t.Talkgroup}, nil +} + +const getTalkgroupsWithLearnedByPackedIDs = `-- name: GetTalkgroupsWithLearnedByPackedIDs :many +SELECT +tg.id, tg.system_id, tg.tgid, tg.name, tg.alpha_tag, tg.tg_group, tg.frequency, tg.metadata, tg.tags, tg.alert, tg.alert_config, tg.weight, sys.id, sys.name, +FALSE learned +FROM talkgroups tg +JOIN systems sys ON tg.system_id = sys.id +WHERE (tg.system_id, tg.tgid) = ANY($1) +UNION +SELECT +NULL::UUID, tgl.system_id::INT4, tgl.tgid::INT4, tgl.name, +tgl.alpha_tag, tgl.alpha_tag, NULL::INTEGER, NULL::JSONB, +CASE WHEN tgl.alpha_tag IS NULL THEN NULL ELSE ARRAY[tgl.alpha_tag] END, +TRUE, NULL::JSONB, 1.0, sys.id, sys.name, +TRUE learned +FROM talkgroups_learned tgl +JOIN systems sys ON tgl.system_id = sys.id +WHERE (tgl.system_id, tgl.tgid) = ANY($1); +` + +type GetTalkgroupsWithLearnedByPackedIDsRow struct { + Talkgroup Talkgroup `json:"talkgroup"` + System System `json:"system"` + Learned bool `json:"learned"` +} + +func (q *Queries) GetTalkgroupsWithLearnedByPackedIDs(ctx context.Context, ids []TalkgroupT) ([]GetTalkgroupsWithLearnedByPackedIDsRow, error) { + rows, err := q.db.Query(ctx, getTalkgroupsWithLearnedByPackedIDs, ids) + if err != nil { + return nil, err + } + defer rows.Close() + var items []GetTalkgroupsWithLearnedByPackedIDsRow + for rows.Next() { + var i GetTalkgroupsWithLearnedByPackedIDsRow + if err := rows.Scan( + &i.Talkgroup.ID, + &i.Talkgroup.SystemID, + &i.Talkgroup.Tgid, + &i.Talkgroup.Name, + &i.Talkgroup.AlphaTag, + &i.Talkgroup.TgGroup, + &i.Talkgroup.Frequency, + &i.Talkgroup.Metadata, + &i.Talkgroup.Tags, + &i.Talkgroup.Alert, + &i.Talkgroup.AlertConfig, + &i.Talkgroup.Weight, + &i.System.ID, + &i.System.Name, + &i.Learned, + ); err != nil { + return nil, err + } + items = append(items, i) + } + if err := rows.Err(); err != nil { + return nil, err + } + return items, nil +} + +const getTalkgroupsByPackedIDs = `-- name: GetTalkgroupsByPackedIDs :many +SELECT tg.id, tg.system_id, tg.tgid, tg.name, tg.alpha_tag, tg.tg_group, tg.frequency, tg.metadata, tg.tags, tg.alert, tg.alert_config, tg.weight, sys.id, sys.name FROM talkgroups tg +JOIN systems sys ON tg.system_id = sys.id +WHERE (tg.system_id, tg.tgid) = ANY($1) +` + +type GetTalkgroupsByPackedIDsRow struct { + Talkgroup Talkgroup `json:"talkgroup"` + System System `json:"system"` +} + +func (q *Queries) GetTalkgroupsByPackedIDs(ctx context.Context, idtuple []TalkgroupT) ([]GetTalkgroupsByPackedIDsRow, error) { + rows, err := q.db.Query(ctx, getTalkgroupsByPackedIDs, idtuple) + if err != nil { + return nil, err + } + defer rows.Close() + var items []GetTalkgroupsByPackedIDsRow + for rows.Next() { + var i GetTalkgroupsByPackedIDsRow + if err := rows.Scan( + &i.Talkgroup.ID, + &i.Talkgroup.SystemID, + &i.Talkgroup.Tgid, + &i.Talkgroup.Name, + &i.Talkgroup.AlphaTag, + &i.Talkgroup.TgGroup, + &i.Talkgroup.Frequency, + &i.Talkgroup.Metadata, + &i.Talkgroup.Tags, + &i.Talkgroup.Alert, + &i.Talkgroup.AlertConfig, + &i.Talkgroup.Weight, + &i.System.ID, + &i.System.Name, + ); err != nil { + return nil, err + } + items = append(items, i) + } + if err := rows.Err(); err != nil { + return nil, err + } + return items, nil +} + + diff --git a/pkg/database/talkgroups.sql.go b/pkg/database/talkgroups.sql.go index 732b26e..1a2e37c 100644 --- a/pkg/database/talkgroups.sql.go +++ b/pkg/database/talkgroups.sql.go @@ -10,6 +10,8 @@ import ( "dynatron.me/x/stillbox/internal/jsontypes" "dynatron.me/x/stillbox/pkg/alerting/rules" + "github.com/google/uuid" + "github.com/jackc/pgx/v5/pgtype" ) const bulkSetTalkgroupTags = `-- name: BulkSetTalkgroupTags :exec @@ -17,7 +19,7 @@ UPDATE talkgroups SET tags = $2 WHERE id = ANY($1) ` -func (q *Queries) BulkSetTalkgroupTags(ctx context.Context, iD int64, tags []string) error { +func (q *Queries) BulkSetTalkgroupTags(ctx context.Context, iD uuid.UUID, tags []string) error { _, err := q.db.Exec(ctx, bulkSetTalkgroupTags, iD, tags) return err } @@ -35,14 +37,14 @@ func (q *Queries) GetSystemName(ctx context.Context, systemID int) (string, erro const getTalkgroup = `-- name: GetTalkgroup :one SELECT talkgroups.id, talkgroups.system_id, talkgroups.tgid, talkgroups.name, talkgroups.alpha_tag, talkgroups.tg_group, talkgroups.frequency, talkgroups.metadata, talkgroups.tags, talkgroups.alert, talkgroups.alert_config, talkgroups.weight FROM talkgroups -WHERE id = systg2id($1, $2) +WHERE (system_id, tgid) = ($1, $2) ` type GetTalkgroupRow struct { Talkgroup Talkgroup `json:"talkgroup"` } -func (q *Queries) GetTalkgroup(ctx context.Context, systemID int, tgid int) (GetTalkgroupRow, error) { +func (q *Queries) GetTalkgroup(ctx context.Context, systemID int32, tgid int32) (GetTalkgroupRow, error) { row := q.db.QueryRow(ctx, getTalkgroup, systemID, tgid) var i GetTalkgroupRow err := row.Scan( @@ -112,7 +114,7 @@ tg.id, tg.system_id, tg.tgid, tg.name, tg.alpha_tag, tg.tg_group, tg.frequency, FALSE learned FROM talkgroups tg JOIN systems sys ON tg.system_id = sys.id -WHERE tg.id = systg2id($1, $2) +WHERE (tg.system_id, tg.tgid) = ($1, $2) UNION SELECT tgl.id::INT8, tgl.system_id::INT4, tgl.tgid::INT4, tgl.name, @@ -131,7 +133,7 @@ type GetTalkgroupWithLearnedRow struct { Learned bool `json:"learned"` } -func (q *Queries) GetTalkgroupWithLearned(ctx context.Context, systemID int, tgid int) (GetTalkgroupWithLearnedRow, error) { +func (q *Queries) GetTalkgroupWithLearned(ctx context.Context, systemID int32, tgid int32) (GetTalkgroupWithLearnedRow, error) { row := q.db.QueryRow(ctx, getTalkgroupWithLearned, systemID, tgid) var i GetTalkgroupWithLearnedRow err := row.Scan( @@ -154,52 +156,6 @@ func (q *Queries) GetTalkgroupWithLearned(ctx context.Context, systemID int, tgi return i, err } -const getTalkgroupsByPackedIDs = `-- name: GetTalkgroupsByPackedIDs :many -SELECT tg.id, tg.system_id, tg.tgid, tg.name, tg.alpha_tag, tg.tg_group, tg.frequency, tg.metadata, tg.tags, tg.alert, tg.alert_config, tg.weight, sys.id, sys.name FROM talkgroups tg -JOIN systems sys ON tg.system_id = sys.id -WHERE tg.id = ANY($1::INT8[]) -` - -type GetTalkgroupsByPackedIDsRow struct { - Talkgroup Talkgroup `json:"talkgroup"` - System System `json:"system"` -} - -func (q *Queries) GetTalkgroupsByPackedIDs(ctx context.Context, dollar_1 []int64) ([]GetTalkgroupsByPackedIDsRow, error) { - rows, err := q.db.Query(ctx, getTalkgroupsByPackedIDs, dollar_1) - if err != nil { - return nil, err - } - defer rows.Close() - var items []GetTalkgroupsByPackedIDsRow - for rows.Next() { - var i GetTalkgroupsByPackedIDsRow - if err := rows.Scan( - &i.Talkgroup.ID, - &i.Talkgroup.SystemID, - &i.Talkgroup.Tgid, - &i.Talkgroup.Name, - &i.Talkgroup.AlphaTag, - &i.Talkgroup.TgGroup, - &i.Talkgroup.Frequency, - &i.Talkgroup.Metadata, - &i.Talkgroup.Tags, - &i.Talkgroup.Alert, - &i.Talkgroup.AlertConfig, - &i.Talkgroup.Weight, - &i.System.ID, - &i.System.Name, - ); err != nil { - return nil, err - } - items = append(items, i) - } - if err := rows.Err(); err != nil { - return nil, err - } - return items, nil -} - const getTalkgroupsWithAllTags = `-- name: GetTalkgroupsWithAllTags :many SELECT talkgroups.id, talkgroups.system_id, talkgroups.tgid, talkgroups.name, talkgroups.alpha_tag, talkgroups.tg_group, talkgroups.frequency, talkgroups.metadata, talkgroups.tags, talkgroups.alert, talkgroups.alert_config, talkgroups.weight FROM talkgroups WHERE tags && ARRAY[$1] @@ -292,7 +248,7 @@ FROM talkgroups tg JOIN systems sys ON tg.system_id = sys.id UNION SELECT -tgl.id::INT8, tgl.system_id::INT4, tgl.tgid::INT4, tgl.name, +NULL::UUID, tgl.system_id::INT4, tgl.tgid::INT4, tgl.name, tgl.alpha_tag, tgl.alpha_tag, NULL::INTEGER, NULL::JSONB, CASE WHEN tgl.alpha_tag IS NULL THEN NULL ELSE ARRAY[tgl.alpha_tag] END, TRUE, NULL::JSONB, 1.0, sys.id, sys.name, @@ -344,67 +300,6 @@ func (q *Queries) GetTalkgroupsWithLearned(ctx context.Context) ([]GetTalkgroups return items, nil } -const getTalkgroupsWithLearnedByPackedIDs = `-- name: GetTalkgroupsWithLearnedByPackedIDs :many -SELECT -tg.id, tg.system_id, tg.tgid, tg.name, tg.alpha_tag, tg.tg_group, tg.frequency, tg.metadata, tg.tags, tg.alert, tg.alert_config, tg.weight, sys.id, sys.name, -FALSE learned -FROM talkgroups tg -JOIN systems sys ON tg.system_id = sys.id -WHERE tg.id = ANY($1::INT8[]) -UNION -SELECT -tgl.id::INT8, tgl.system_id::INT4, tgl.tgid::INT4, tgl.name, -tgl.alpha_tag, tgl.alpha_tag, NULL::INTEGER, NULL::JSONB, -CASE WHEN tgl.alpha_tag IS NULL THEN NULL ELSE ARRAY[tgl.alpha_tag] END, -TRUE, NULL::JSONB, 1.0, sys.id, sys.name, -TRUE learned -FROM talkgroups_learned tgl -JOIN systems sys ON tgl.system_id = sys.id -WHERE systg2id(tgl.system_id, tgl.tgid) = ANY($1::INT8[]) AND ignored IS NOT TRUE -` - -type GetTalkgroupsWithLearnedByPackedIDsRow struct { - Talkgroup Talkgroup `json:"talkgroup"` - System System `json:"system"` - Learned bool `json:"learned"` -} - -func (q *Queries) GetTalkgroupsWithLearnedByPackedIDs(ctx context.Context, dollar_1 []int64) ([]GetTalkgroupsWithLearnedByPackedIDsRow, error) { - rows, err := q.db.Query(ctx, getTalkgroupsWithLearnedByPackedIDs, dollar_1) - if err != nil { - return nil, err - } - defer rows.Close() - var items []GetTalkgroupsWithLearnedByPackedIDsRow - for rows.Next() { - var i GetTalkgroupsWithLearnedByPackedIDsRow - if err := rows.Scan( - &i.Talkgroup.ID, - &i.Talkgroup.SystemID, - &i.Talkgroup.Tgid, - &i.Talkgroup.Name, - &i.Talkgroup.AlphaTag, - &i.Talkgroup.TgGroup, - &i.Talkgroup.Frequency, - &i.Talkgroup.Metadata, - &i.Talkgroup.Tags, - &i.Talkgroup.Alert, - &i.Talkgroup.AlertConfig, - &i.Talkgroup.Weight, - &i.System.ID, - &i.System.Name, - &i.Learned, - ); err != nil { - return nil, err - } - items = append(items, i) - } - if err := rows.Err(); err != nil { - return nil, err - } - return items, nil -} - const getTalkgroupsWithLearnedBySystem = `-- name: GetTalkgroupsWithLearnedBySystem :many SELECT tg.id, tg.system_id, tg.tgid, tg.name, tg.alpha_tag, tg.tg_group, tg.frequency, tg.metadata, tg.tags, tg.alert, tg.alert_config, tg.weight, sys.id, sys.name, @@ -414,7 +309,7 @@ JOIN systems sys ON tg.system_id = sys.id WHERE tg.system_id = $1 UNION SELECT -tgl.id::INT8, tgl.system_id::INT4, tgl.tgid::INT4, tgl.name, +NULL::UUID, tgl.system_id::INT4, tgl.tgid::INT4, tgl.name, tgl.alpha_tag, tgl.alpha_tag, NULL::INTEGER, NULL::JSONB, CASE WHEN tgl.alpha_tag IS NULL THEN NULL ELSE ARRAY[tgl.alpha_tag] END, TRUE, NULL::JSONB, 1.0, sys.id, sys.name, @@ -488,7 +383,7 @@ SET alert = COALESCE($7, alert), alert_config = COALESCE($8, alert_config), weight = COALESCE($9, weight) -WHERE id = $10 +WHERE id = $10 OR (system_id = $11 AND tgid = $12) RETURNING id, system_id, tgid, name, alpha_tag, tg_group, frequency, metadata, tags, alert, alert_config, weight ` @@ -502,7 +397,9 @@ type UpdateTalkgroupParams struct { Alert *bool `json:"alert"` AlertConfig rules.AlertRules `json:"alert_config"` Weight *float32 `json:"weight"` - ID int64 `json:"id"` + ID pgtype.UUID `json:"id"` + SystemID *int32 `json:"system_id"` + Tgid *int32 `json:"tgid"` } func (q *Queries) UpdateTalkgroup(ctx context.Context, arg UpdateTalkgroupParams) (Talkgroup, error) { @@ -517,6 +414,8 @@ func (q *Queries) UpdateTalkgroup(ctx context.Context, arg UpdateTalkgroupParams arg.AlertConfig, arg.Weight, arg.ID, + arg.SystemID, + arg.Tgid, ) var i Talkgroup err := row.Scan( diff --git a/pkg/rest/talkgroups.go b/pkg/rest/talkgroups.go index 7185148..1a539f1 100644 --- a/pkg/rest/talkgroups.go +++ b/pkg/rest/talkgroups.go @@ -97,7 +97,6 @@ func (tga *talkgroupAPI) put(w http.ResponseWriter, r *http.Request) { wErr(w, r, badRequest(err)) return } - input.ID = id.ToID().Pack() record, err := tgs.UpdateTG(ctx, input) if err != nil { diff --git a/pkg/talkgroups/cache.go b/pkg/talkgroups/cache.go index e5463c7..18f30b6 100644 --- a/pkg/talkgroups/cache.go +++ b/pkg/talkgroups/cache.go @@ -40,7 +40,7 @@ type Store interface { Hint(ctx context.Context, tgs []ID) error // Load loads the provided packed talkgroup IDs into the Store. - Load(ctx context.Context, tgs []int64) error + Load(ctx context.Context, tgs []database.TalkgroupT) error // Invalidate invalidates any caching in the Store. Invalidate() @@ -98,19 +98,19 @@ func NewCache() Store { func (t *cache) Hint(ctx context.Context, tgs []ID) error { t.RLock() - var toLoad []int64 + var toLoad []database.TalkgroupT if len(t.tgs) > len(tgs)/2 { // TODO: instrument this for _, tg := range tgs { _, ok := t.tgs[tg] if !ok { - toLoad = append(toLoad, tg.Pack()) + toLoad = append(toLoad, tg.Tuple()) } } } else { - toLoad = make([]int64, 0, len(tgs)) + toLoad = make([]database.TalkgroupT, 0, len(tgs)) for _, g := range tgs { - toLoad = append(toLoad, g.Pack()) + toLoad = append(toLoad, g.Tuple()) } } @@ -180,7 +180,7 @@ func (t *cache) TGs(ctx context.Context, tgs IDs) ([]*Talkgroup, error) { } t.RUnlock() - tgRecords, err := database.FromCtx(ctx).GetTalkgroupsWithLearnedByPackedIDs(ctx, toGet.Packed()) + tgRecords, err := database.FromCtx(ctx).GetTalkgroupsWithLearnedByPackedIDs(ctx, toGet.Tuples()) if err != nil { return nil, err } @@ -196,7 +196,7 @@ func (t *cache) TGs(ctx context.Context, tgs IDs) ([]*Talkgroup, error) { return addToRowList(t, r, tgRecords) } -func (t *cache) Load(ctx context.Context, tgs []int64) error { +func (t *cache) Load(ctx context.Context, tgs []database.TalkgroupT) error { tgRecords, err := database.FromCtx(ctx).GetTalkgroupsWithLearnedByPackedIDs(ctx, tgs) if err != nil { return err @@ -245,7 +245,7 @@ func (t *cache) TG(ctx context.Context, tg ID) (*Talkgroup, error) { return rec, nil } - recs, err := database.FromCtx(ctx).GetTalkgroupsWithLearnedByPackedIDs(ctx, []int64{tg.Pack()}) + recs, err := database.FromCtx(ctx).GetTalkgroupsWithLearnedByPackedIDs(ctx, []database.TalkgroupT{tg.Tuple()}) switch err { case nil: case pgx.ErrNoRows: @@ -290,7 +290,7 @@ func (t *cache) SystemName(ctx context.Context, id int) (name string, has bool) } func (t *cache) UpdateTG(ctx context.Context, input database.UpdateTalkgroupParams) (*Talkgroup, error) { - sysName, has := t.SystemName(ctx, int(Unpack(input.ID).System)) + sysName, has := t.SystemName(ctx, int(*input.SystemID)) if !has { return nil, ErrNoSuchSystem } diff --git a/pkg/talkgroups/import.go b/pkg/talkgroups/import.go index 05c8d2e..e58a592 100644 --- a/pkg/talkgroups/import.go +++ b/pkg/talkgroups/import.go @@ -11,6 +11,8 @@ import ( "strings" "time" + "github.com/google/uuid" + "dynatron.me/x/stillbox/internal/jsontypes" "dynatron.me/x/stillbox/pkg/database" ) @@ -116,7 +118,7 @@ func (rr *radioReferenceImporter) importTalkgroups(ctx context.Context, sys int, gn := groupName // must take a copy tgs = append(tgs, Talkgroup{ Talkgroup: database.Talkgroup{ - ID: tgt.Pack(), + ID: uuid.New(), Tgid: int32(tgt.Talkgroup), SystemID: int32(tgt.System), Name: &fields[4], diff --git a/pkg/talkgroups/talkgroup.go b/pkg/talkgroups/talkgroup.go index b9b746b..2e5b269 100644 --- a/pkg/talkgroups/talkgroup.go +++ b/pkg/talkgroups/talkgroup.go @@ -26,10 +26,10 @@ type ID struct { type IDs []ID -func (ids *IDs) Packed() []int64 { - r := make([]int64, len(*ids)) +func (ids *IDs) Tuples() []database.TalkgroupT { + r := make([]database.TalkgroupT, len(*ids)) for i := range *ids { - r[i] = (*ids)[i].Pack() + r[i] = (*ids)[i].Tuple() } return r @@ -46,15 +46,10 @@ func TG[T intId, U intId](sys T, tgid U) ID { } } -func (t ID) Pack() int64 { - // P25 system IDs are 12 bits, so we can fit them in a signed 8 byte int (int64, pg INT8) - return int64((int64(t.System) << 32) | int64(t.Talkgroup)) -} - -func Unpack(id int64) ID { - return ID{ - System: uint32(id >> 32), - Talkgroup: uint32(id & 0xffffffff), +func (t ID) Tuple() database.TalkgroupT { + return database.TalkgroupT{ + System: t.System, + Talkgroup: t.Talkgroup, } } diff --git a/sql/postgres/migrations/002_reid.down.sql b/sql/postgres/migrations/002_reid.down.sql new file mode 100644 index 0000000..b27dba3 --- /dev/null +++ b/sql/postgres/migrations/002_reid.down.sql @@ -0,0 +1,9 @@ +DROP INDEX IF EXISTS talkgroups_system_tgid_idx; + +ALTER TABLE talkgroups ALTER COLUMN id SET DATA TYPE INT8 USING (systg2id(system_id, tgid)); + +ALTER TABLE talkgroups DROP COLUMN IF EXISTS tgid; +ALTER TABLE talkgroups ADD COLUMN IF NOT EXISTS tgid INT4 NOT NULL GENERATED ALWAYS AS (id & x'ffffffff'::BIGINT) STORED, + +ALTER TABLE talkgroups DROP COLUMN IF EXISTS system_id; +ALTER TABLE talkgroups ADD COLUMN IF NOT EXISTS system_id INT4 REFERENCES systems(id) NOT NULL GENERATED ALWAYS AS (id >> 32) STORED; diff --git a/sql/postgres/migrations/002_reid.up.sql b/sql/postgres/migrations/002_reid.up.sql new file mode 100644 index 0000000..b0d91d7 --- /dev/null +++ b/sql/postgres/migrations/002_reid.up.sql @@ -0,0 +1,7 @@ +ALTER TABLE talkgroups ALTER COLUMN system_id DROP EXPRESSION; + +ALTER TABLE talkgroups ALTER COLUMN tgid DROP EXPRESSION; + +ALTER TABLE talkgroups ALTER COLUMN id SET DATA TYPE UUID USING (gen_random_uuid()); + +CREATE INDEX IF NOT EXISTS talkgroups_system_tgid_idx ON talkgroups (system_id, tgid); diff --git a/sql/postgres/migrations/flattened_initial.sql b/sql/postgres/migrations/flattened_initial.sql new file mode 100644 index 0000000..1c4397d --- /dev/null +++ b/sql/postgres/migrations/flattened_initial.sql @@ -0,0 +1,157 @@ +CREATE TABLE IF NOT EXISTS users( + id SERIAL PRIMARY KEY, + 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 SERIAL PRIMARY KEY, + 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 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 +$$; + +CREATE TABLE IF NOT EXISTS talkgroups( + id UUID PRIMARY KEY, + 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 +); + +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 SERIAL PRIMARY KEY, + system_id INTEGER REFERENCES systems(id) NOT NULL, + tgid INTEGER NOT NULL, + name TEXT NOT NULL, + alpha_tag TEXT, + ignored BOOLEAN, + UNIQUE (system_id, tgid, name) +); + +CREATE TABLE IF NOT EXISTS alerts( + id UUID PRIMARY KEY, + 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 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 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 +); + +CREATE OR REPLACE TRIGGER learn_tg AFTER INSERT ON calls +FOR EACH ROW EXECUTE FUNCTION learn_talkgroup(); + +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) +); diff --git a/sql/postgres/queries/talkgroups.sql b/sql/postgres/queries/talkgroups.sql index 732a848..f2e7a1e 100644 --- a/sql/postgres/queries/talkgroups.sql +++ b/sql/postgres/queries/talkgroups.sql @@ -26,12 +26,7 @@ WHERE id = ANY($1); -- name: GetTalkgroup :one SELECT sqlc.embed(talkgroups) FROM talkgroups -WHERE id = systg2id(sqlc.arg(system_id), sqlc.arg(tgid)); - --- name: GetTalkgroupsByPackedIDs :many -SELECT sqlc.embed(tg), sqlc.embed(sys) FROM talkgroups tg -JOIN systems sys ON tg.system_id = sys.id -WHERE tg.id = ANY($1::INT8[]); +WHERE (system_id, tgid) = (@system_id, @tgid); -- name: GetTalkgroupWithLearned :one SELECT @@ -39,7 +34,7 @@ sqlc.embed(tg), sqlc.embed(sys), FALSE learned FROM talkgroups tg JOIN systems sys ON tg.system_id = sys.id -WHERE tg.id = systg2id(sqlc.arg(system_id), sqlc.arg(tgid)) +WHERE (tg.system_id, tg.tgid) = (sqlc.arg(system_id), sqlc.arg(tgid)) UNION SELECT tgl.id::INT8, tgl.system_id::INT4, tgl.tgid::INT4, tgl.name, @@ -51,24 +46,6 @@ FROM talkgroups_learned tgl JOIN systems sys ON tgl.system_id = sys.id WHERE tgl.system_id = sqlc.arg(system_id) AND tgl.tgid = sqlc.arg(tgid) AND ignored IS NOT TRUE; --- name: GetTalkgroupsWithLearnedByPackedIDs :many -SELECT -sqlc.embed(tg), sqlc.embed(sys), -FALSE learned -FROM talkgroups tg -JOIN systems sys ON tg.system_id = sys.id -WHERE tg.id = ANY($1::INT8[]) -UNION -SELECT -tgl.id::INT8, tgl.system_id::INT4, tgl.tgid::INT4, tgl.name, -tgl.alpha_tag, tgl.alpha_tag, NULL::INTEGER, NULL::JSONB, -CASE WHEN tgl.alpha_tag IS NULL THEN NULL ELSE ARRAY[tgl.alpha_tag] END, -TRUE, NULL::JSONB, 1.0, sys.id, sys.name, -TRUE learned -FROM talkgroups_learned tgl -JOIN systems sys ON tgl.system_id = sys.id -WHERE systg2id(tgl.system_id, tgl.tgid) = ANY($1::INT8[]) AND ignored IS NOT TRUE; - -- name: GetTalkgroupsWithLearnedBySystem :many SELECT sqlc.embed(tg), sqlc.embed(sys), @@ -78,7 +55,7 @@ JOIN systems sys ON tg.system_id = sys.id WHERE tg.system_id = @system UNION SELECT -tgl.id::INT8, tgl.system_id::INT4, tgl.tgid::INT4, tgl.name, +NULL::UUID, tgl.system_id::INT4, tgl.tgid::INT4, tgl.name, tgl.alpha_tag, tgl.alpha_tag, NULL::INTEGER, NULL::JSONB, CASE WHEN tgl.alpha_tag IS NULL THEN NULL ELSE ARRAY[tgl.alpha_tag] END, TRUE, NULL::JSONB, 1.0, sys.id, sys.name, @@ -95,7 +72,7 @@ FROM talkgroups tg JOIN systems sys ON tg.system_id = sys.id UNION SELECT -tgl.id::INT8, tgl.system_id::INT4, tgl.tgid::INT4, tgl.name, +NULL::UUID, tgl.system_id::INT4, tgl.tgid::INT4, tgl.name, tgl.alpha_tag, tgl.alpha_tag, NULL::INTEGER, NULL::JSONB, CASE WHEN tgl.alpha_tag IS NULL THEN NULL ELSE ARRAY[tgl.alpha_tag] END, TRUE, NULL::JSONB, 1.0, sys.id, sys.name, @@ -119,5 +96,5 @@ SET alert = COALESCE(sqlc.narg('alert'), alert), alert_config = COALESCE(sqlc.narg('alert_config'), alert_config), weight = COALESCE(sqlc.narg('weight'), weight) -WHERE id = @id +WHERE id = sqlc.narg('id') OR (system_id = sqlc.narg('system_id') AND tgid = sqlc.narg('tgid')) RETURNING *; diff --git a/sql/sqlc.yaml b/sql/sqlc.yaml index 342e2fb..55a0959 100644 --- a/sql/sqlc.yaml +++ b/sql/sqlc.yaml @@ -37,3 +37,7 @@ sql: import: "dynatron.me/x/stillbox/internal/jsontypes" type: "Metadata" nullable: true + - column: "(talkgroups.system_id, talkgroups.tgid)" + go_type: + import: "dynatron.me/x/stillbox/pkg/talkgroups" + type: "ID"