clean up SQL

This commit is contained in:
Daniel 2024-07-15 19:03:48 -04:00
parent 47fe2de326
commit 2db6cae67e
7 changed files with 147 additions and 7 deletions

View file

@ -10,6 +10,7 @@ type Config struct {
JWTSecret string `yaml:"jwtsecret"` JWTSecret string `yaml:"jwtsecret"`
Listen string `yaml:"listen"` Listen string `yaml:"listen"`
Public bool `yaml:"public"` Public bool `yaml:"public"`
Domain string `yaml:"domain"`
} }
type DB struct { type DB struct {

View file

@ -11,11 +11,43 @@ import (
type Apikey struct { type Apikey struct {
ID int32 ID int32
Owner pgtype.Int4 Owner pgtype.Int4
Apikey string ApiKey string
} }
type Call struct { type Call struct {
ID pgtype.UUID ID pgtype.UUID
Submitter int32
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
}
type Setting struct {
Name string
UpdatedBy pgtype.Int4
Value []byte
}
type System struct {
ID int32
Name string
}
type Talkgroup struct {
ID int32
System int32
Name pgtype.Text
Frequency pgtype.Int4
GroupID pgtype.Int4
} }
type User struct { type User struct {

View file

@ -1,7 +1,7 @@
// Code generated by sqlc. DO NOT EDIT. // Code generated by sqlc. DO NOT EDIT.
// versions: // versions:
// sqlc v1.26.0 // sqlc v1.26.0
// source: query.sql // source: users.sql
package database package database
@ -47,6 +47,15 @@ func (q *Queries) CreateUser(ctx context.Context, arg CreateUserParams) (User, e
return i, err return i, err
} }
const deleteUser = `-- name: DeleteUser :exec
DELETE FROM users WHERE username = $1
`
func (q *Queries) DeleteUser(ctx context.Context, username string) error {
_, err := q.db.Exec(ctx, deleteUser, username)
return err
}
const getUserByID = `-- name: GetUserByID :one const getUserByID = `-- name: GetUserByID :one
SELECT id, username, password, email, is_admin, prefs FROM users SELECT id, username, password, email, is_admin, prefs FROM users
WHERE id = $1 LIMIT 1 WHERE id = $1 LIMIT 1
@ -66,6 +75,25 @@ func (q *Queries) GetUserByID(ctx context.Context, id int32) (User, error) {
return i, err return i, err
} }
const getUserByUID = `-- name: GetUserByUID :one
SELECT id, username, password, email, is_admin, prefs FROM users
WHERE id = $1 LIMIT 1
`
func (q *Queries) GetUserByUID(ctx context.Context, id int32) (User, error) {
row := q.db.QueryRow(ctx, getUserByUID, id)
var i User
err := row.Scan(
&i.ID,
&i.Username,
&i.Password,
&i.Email,
&i.IsAdmin,
&i.Prefs,
)
return i, err
}
const getUserByUsername = `-- name: GetUserByUsername :one const getUserByUsername = `-- name: GetUserByUsername :one
SELECT id, username, password, email, is_admin, prefs FROM users SELECT id, username, password, email, is_admin, prefs FROM users
WHERE username = $1 LIMIT 1 WHERE username = $1 LIMIT 1
@ -115,3 +143,17 @@ func (q *Queries) GetUsers(ctx context.Context) ([]User, error) {
} }
return items, nil return items, nil
} }
const updatePassword = `-- name: UpdatePassword :exec
UPDATE users SET password = $2 WHERE username = $1
`
type UpdatePasswordParams struct {
Username string
Password string
}
func (q *Queries) UpdatePassword(ctx context.Context, arg UpdatePasswordParams) error {
_, err := q.db.Exec(ctx, updatePassword, arg.Username, arg.Password)
return err
}

View file

@ -67,6 +67,13 @@ func (s *Server) routeAuth(w http.ResponseWriter, r *http.Request) {
http.Error(w, err.Error(), http.StatusUnauthorized) http.Error(w, err.Error(), http.StatusUnauthorized)
return return
} }
http.SetCookie(w, &http.Cookie{
Name: "jwt",
Value: tok,
HttpOnly: true,
Secure: true,
Domain: s.conf.Domain,
})
jr := struct { jr := struct {
JWT string `json:"jwt"` JWT string `json:"jwt"`

View file

@ -1,8 +1,56 @@
CREATE TABLE IF NOT EXISTS users( CREATE TABLE IF NOT EXISTS users(
id SERIAL PRIMARY KEY, id SERIAL PRIMARY KEY,
username VARCHAR (255) UNIQUE NOT NULL, username VARCHAR (255) UNIQUE NOT NULL,
password VARCHAR(255) NOT NULL, password TEXT NOT NULL,
email VARCHAR(255) NOT NULL, email TEXT NOT NULL,
is_admin BOOLEAN is_admin BOOLEAN,
prefs JSONB
); );
CREATE INDEX IF NOT EXISTS users_username ON users(username);
CREATE TABLE IF NOT EXISTS apikeys(
id SERIAL PRIMARY KEY,
owner INTEGER REFERENCES users(id),
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 NOT NULL,
system INTEGER REFERENCES systems(id) NOT NULL,
name TEXT,
frequency INTEGER,
group_id INTEGER,
PRIMARY KEY (tgid, system)
);
CREATE TABLE IF NOT EXISTS calls(
id UUID PRIMARY KEY,
submitter INTEGER REFERENCES apikeys(id) NOT NULL,
system INTEGER NOT NULL,
talkgroup INTEGER NOT NULL,
date TIMESTAMP NOT NULL,
audio_name TEXT,
audio_blob BYTEA,
audio_type TEXT,
audio_url TEXT,
frequency INTEGER,
frequencies JSONB,
patches JSONB,
tg_label TEXT,
source TEXT,
FOREIGN KEY (system, talkgroup) REFERENCES talkgroups(system, id)
);
CREATE INDEX IF NOT EXISTS calls_date_tg ON calls(talkgroup, date);
CREATE TABLE IF NOT EXISTS settings(
name TEXT PRIMARY KEY,
updated_by INTEGER REFERENCES users(id),
value JSONB
);

View file

@ -6,6 +6,10 @@ WHERE id = $1 LIMIT 1;
SELECT * FROM users SELECT * FROM users
WHERE username = $1 LIMIT 1; WHERE username = $1 LIMIT 1;
-- name: GetUserByUID :one
SELECT * FROM users
WHERE id = $1 LIMIT 1;
-- name: GetUsers :many -- name: GetUsers :many
SELECT * FROM users; SELECT * FROM users;
@ -17,3 +21,9 @@ INSERT INTO users (
is_admin is_admin
) VALUES ($1, $2, $3, $4) ) VALUES ($1, $2, $3, $4)
RETURNING *; RETURNING *;
-- name: DeleteUser :exec
DELETE FROM users WHERE username = $1;
-- name: UpdatePassword :exec
UPDATE users SET password = $2 WHERE username = $1;

View file

@ -1,7 +1,7 @@
version: "2" version: "2"
sql: sql:
- engine: "postgresql" - engine: "postgresql"
queries: "postgres/query.sql" queries: "postgres/queries"
schema: "postgres/migrations" schema: "postgres/migrations"
gen: gen:
go: go: