mirror of
https://github.com/SecurityBrewery/catalyst.git
synced 2025-12-06 07:12:46 +01:00
refactor: remove pocketbase (#1138)
This commit is contained in:
112
app/database/db.go
Normal file
112
app/database/db.go
Normal file
@@ -0,0 +1,112 @@
|
||||
package database
|
||||
|
||||
import (
|
||||
"context"
|
||||
"crypto/rand"
|
||||
"database/sql"
|
||||
"fmt"
|
||||
"log/slog"
|
||||
"os"
|
||||
"path/filepath"
|
||||
"strings"
|
||||
"testing"
|
||||
"time"
|
||||
|
||||
_ "github.com/mattn/go-sqlite3" // import sqlite driver
|
||||
"github.com/stretchr/testify/require"
|
||||
|
||||
"github.com/SecurityBrewery/catalyst/app/database/sqlc"
|
||||
)
|
||||
|
||||
const sqliteDriver = "sqlite3"
|
||||
|
||||
func DB(ctx context.Context, dir string) (*sqlc.Queries, func(), error) {
|
||||
filename := filepath.Join(dir, "data.db")
|
||||
|
||||
slog.InfoContext(ctx, "Connecting to database", "path", filename)
|
||||
|
||||
// see https://briandouglas.ie/sqlite-defaults/ for more details
|
||||
pragmas := []string{
|
||||
// Enable WAL mode for better concurrency
|
||||
"journal_mode=WAL",
|
||||
// Enable synchronous mode for better data integrity
|
||||
"synchronous=NORMAL",
|
||||
// Set busy timeout to 5 seconds
|
||||
"busy_timeout=5000",
|
||||
// Set cache size to 20MB
|
||||
"cache_size=-20000",
|
||||
// Enable foreign key checks
|
||||
"foreign_keys=ON",
|
||||
// Enable incremental vacuuming
|
||||
"auto_vacuum=INCREMENTAL",
|
||||
// Set temp store to memory
|
||||
"temp_store=MEMORY",
|
||||
// Set mmap size to 2GB
|
||||
"mmap_size=2147483648",
|
||||
// Set page size to 8192
|
||||
"page_size=8192",
|
||||
}
|
||||
|
||||
_ = os.MkdirAll(filepath.Dir(filename), 0o755)
|
||||
|
||||
write, err := sql.Open(sqliteDriver, fmt.Sprintf("file:%s", filename))
|
||||
if err != nil {
|
||||
return nil, nil, fmt.Errorf("failed to open database: %w", err)
|
||||
}
|
||||
|
||||
write.SetMaxOpenConns(1)
|
||||
write.SetConnMaxIdleTime(time.Minute)
|
||||
|
||||
for _, pragma := range pragmas {
|
||||
if _, err := write.ExecContext(ctx, fmt.Sprintf("PRAGMA %s", pragma)); err != nil {
|
||||
return nil, nil, fmt.Errorf("failed to set pragma %s: %w", pragma, err)
|
||||
}
|
||||
}
|
||||
|
||||
read, err := sql.Open(sqliteDriver, fmt.Sprintf("file:%s?mode=ro", filename))
|
||||
if err != nil {
|
||||
return nil, nil, fmt.Errorf("failed to open database: %w", err)
|
||||
}
|
||||
|
||||
read.SetMaxOpenConns(100)
|
||||
read.SetConnMaxIdleTime(time.Minute)
|
||||
|
||||
queries := sqlc.New(read, write)
|
||||
|
||||
return queries, func() {
|
||||
if err := read.Close(); err != nil {
|
||||
slog.Error("failed to close read connection", "error", err)
|
||||
}
|
||||
|
||||
if err := write.Close(); err != nil {
|
||||
slog.Error("failed to close write connection", "error", err)
|
||||
}
|
||||
}, nil
|
||||
}
|
||||
|
||||
func TestDB(t *testing.T, dir string) *sqlc.Queries {
|
||||
queries, cleanup, err := DB(t.Context(), filepath.Join(dir, "data.db"))
|
||||
require.NoError(t, err)
|
||||
t.Cleanup(cleanup)
|
||||
|
||||
return queries
|
||||
}
|
||||
|
||||
func GenerateID(prefix string) string {
|
||||
return strings.ToLower(prefix) + randomstring(12)
|
||||
}
|
||||
|
||||
const base32alphabet = "0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz"
|
||||
|
||||
func randomstring(l int) string {
|
||||
rand.Text()
|
||||
|
||||
src := make([]byte, l)
|
||||
_, _ = rand.Read(src)
|
||||
|
||||
for i := range src {
|
||||
src[i] = base32alphabet[int(src[i])%len(base32alphabet)]
|
||||
}
|
||||
|
||||
return string(src)
|
||||
}
|
||||
21
app/database/db_test.go
Normal file
21
app/database/db_test.go
Normal file
@@ -0,0 +1,21 @@
|
||||
package database_test
|
||||
|
||||
import (
|
||||
"testing"
|
||||
|
||||
"github.com/stretchr/testify/assert"
|
||||
|
||||
"github.com/SecurityBrewery/catalyst/app/database"
|
||||
"github.com/SecurityBrewery/catalyst/app/database/sqlc"
|
||||
)
|
||||
|
||||
func TestDBForeignKeyConstraints(t *testing.T) {
|
||||
t.Parallel()
|
||||
|
||||
queries := database.TestDB(t, t.TempDir())
|
||||
|
||||
assert.Error(t, queries.AssignGroupToUser(t.Context(), sqlc.AssignGroupToUserParams{
|
||||
UserID: "does_not_exist",
|
||||
GroupID: "also_missing",
|
||||
}))
|
||||
}
|
||||
236
app/database/migrations/000_create_pocketbase_tables.up.sql
Normal file
236
app/database/migrations/000_create_pocketbase_tables.up.sql
Normal file
@@ -0,0 +1,236 @@
|
||||
CREATE TABLE IF NOT EXISTS _migrations
|
||||
(
|
||||
file VARCHAR(255) PRIMARY KEY NOT NULL,
|
||||
applied INTEGER NOT NULL
|
||||
);
|
||||
CREATE TABLE IF NOT EXISTS _admins
|
||||
(
|
||||
id TEXT PRIMARY KEY NOT NULL,
|
||||
avatar INTEGER DEFAULT 0 NOT NULL,
|
||||
email TEXT UNIQUE NOT NULL,
|
||||
tokenKey TEXT UNIQUE NOT NULL,
|
||||
passwordHash TEXT NOT NULL,
|
||||
lastResetSentAt TEXT DEFAULT "" NOT NULL,
|
||||
created TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL,
|
||||
updated TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL
|
||||
);
|
||||
CREATE TABLE IF NOT EXISTS _collections
|
||||
(
|
||||
id TEXT PRIMARY KEY NOT NULL,
|
||||
system BOOLEAN DEFAULT FALSE NOT NULL,
|
||||
type TEXT DEFAULT "base" NOT NULL,
|
||||
name TEXT UNIQUE NOT NULL,
|
||||
schema JSON DEFAULT "[]" NOT NULL,
|
||||
indexes JSON DEFAULT "[]" NOT NULL,
|
||||
listRule TEXT DEFAULT NULL,
|
||||
viewRule TEXT DEFAULT NULL,
|
||||
createRule TEXT DEFAULT NULL,
|
||||
updateRule TEXT DEFAULT NULL,
|
||||
deleteRule TEXT DEFAULT NULL,
|
||||
options JSON DEFAULT "{}" NOT NULL,
|
||||
created TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL,
|
||||
updated TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL
|
||||
);
|
||||
CREATE TABLE IF NOT EXISTS _params
|
||||
(
|
||||
id TEXT PRIMARY KEY NOT NULL,
|
||||
key TEXT UNIQUE NOT NULL,
|
||||
value JSON DEFAULT NULL,
|
||||
created TEXT DEFAULT "" NOT NULL,
|
||||
updated TEXT DEFAULT "" NOT NULL
|
||||
);
|
||||
CREATE TABLE IF NOT EXISTS _externalAuths
|
||||
(
|
||||
id TEXT PRIMARY KEY NOT NULL,
|
||||
collectionId TEXT NOT NULL,
|
||||
recordId TEXT NOT NULL,
|
||||
provider TEXT NOT NULL,
|
||||
providerId TEXT NOT NULL,
|
||||
created TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL,
|
||||
updated TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL,
|
||||
---
|
||||
FOREIGN KEY (collectionId) REFERENCES _collections (id) ON UPDATE CASCADE ON DELETE CASCADE
|
||||
);
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS _externalAuths_record_provider_idx on _externalAuths (collectionId, recordId, provider);
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS _externalAuths_collection_provider_idx on _externalAuths (collectionId, provider, providerId);
|
||||
CREATE TABLE IF NOT EXISTS users
|
||||
(
|
||||
avatar TEXT DEFAULT '' NOT NULL,
|
||||
created TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL,
|
||||
email TEXT DEFAULT '' NOT NULL,
|
||||
emailVisibility BOOLEAN DEFAULT FALSE NOT NULL,
|
||||
id TEXT PRIMARY KEY DEFAULT ('r' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
lastLoginAlertSentAt TEXT DEFAULT '' NOT NULL,
|
||||
lastResetSentAt TEXT DEFAULT '' NOT NULL,
|
||||
lastVerificationSentAt TEXT DEFAULT '' NOT NULL,
|
||||
name TEXT DEFAULT '' NOT NULL,
|
||||
passwordHash TEXT NOT NULL,
|
||||
tokenKey TEXT NOT NULL,
|
||||
updated TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL,
|
||||
username TEXT NOT NULL,
|
||||
verified BOOLEAN DEFAULT FALSE NOT NULL
|
||||
);
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS __pb_users_auth__username_idx ON users (username);
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS __pb_users_auth__email_idx ON users (email) WHERE email != '';
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS __pb_users_auth__tokenKey_idx ON users (tokenKey);
|
||||
CREATE TABLE IF NOT EXISTS webhooks
|
||||
(
|
||||
collection TEXT DEFAULT '' NOT NULL,
|
||||
created TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL,
|
||||
destination TEXT DEFAULT '' NOT NULL,
|
||||
id TEXT PRIMARY KEY DEFAULT ('r' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
name TEXT DEFAULT '' NOT NULL,
|
||||
updated TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL
|
||||
);
|
||||
CREATE TABLE IF NOT EXISTS types
|
||||
(
|
||||
created TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL,
|
||||
icon TEXT DEFAULT '' NOT NULL,
|
||||
id TEXT PRIMARY KEY DEFAULT ('r' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
plural TEXT DEFAULT '' NOT NULL,
|
||||
schema JSON DEFAULT NULL,
|
||||
singular TEXT DEFAULT '' NOT NULL,
|
||||
updated TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL
|
||||
);
|
||||
CREATE TABLE IF NOT EXISTS tickets
|
||||
(
|
||||
created TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL,
|
||||
description TEXT DEFAULT '' NOT NULL,
|
||||
id TEXT PRIMARY KEY DEFAULT ('r' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
name TEXT DEFAULT '' NOT NULL,
|
||||
open BOOLEAN DEFAULT FALSE NOT NULL,
|
||||
owner TEXT DEFAULT '' NOT NULL,
|
||||
resolution TEXT DEFAULT '' NOT NULL,
|
||||
schema JSON DEFAULT NULL,
|
||||
state JSON DEFAULT NULL,
|
||||
type TEXT DEFAULT '' NOT NULL,
|
||||
updated TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL
|
||||
);
|
||||
CREATE TABLE IF NOT EXISTS tasks
|
||||
(
|
||||
created TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL,
|
||||
id TEXT PRIMARY KEY DEFAULT ('r' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
name TEXT DEFAULT '' NOT NULL,
|
||||
open BOOLEAN DEFAULT FALSE NOT NULL,
|
||||
owner TEXT DEFAULT '' NOT NULL,
|
||||
ticket TEXT DEFAULT '' NOT NULL,
|
||||
updated TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL
|
||||
);
|
||||
CREATE TABLE IF NOT EXISTS comments
|
||||
(
|
||||
author TEXT DEFAULT '' NOT NULL,
|
||||
created TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL,
|
||||
id TEXT PRIMARY KEY DEFAULT ('r' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
message TEXT DEFAULT '' NOT NULL,
|
||||
ticket TEXT DEFAULT '' NOT NULL,
|
||||
updated TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL
|
||||
);
|
||||
CREATE TABLE IF NOT EXISTS timeline
|
||||
(
|
||||
created TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL,
|
||||
id TEXT PRIMARY KEY DEFAULT ('r' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
message TEXT DEFAULT '' NOT NULL,
|
||||
ticket TEXT DEFAULT '' NOT NULL,
|
||||
time TEXT DEFAULT '' NOT NULL,
|
||||
updated TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL
|
||||
);
|
||||
CREATE TABLE IF NOT EXISTS links
|
||||
(
|
||||
created TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL,
|
||||
id TEXT PRIMARY KEY DEFAULT ('r' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
name TEXT DEFAULT '' NOT NULL,
|
||||
ticket TEXT DEFAULT '' NOT NULL,
|
||||
updated TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL,
|
||||
url TEXT DEFAULT '' NOT NULL
|
||||
);
|
||||
CREATE TABLE IF NOT EXISTS files
|
||||
(
|
||||
blob TEXT DEFAULT '' NOT NULL,
|
||||
created TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL,
|
||||
id TEXT PRIMARY KEY DEFAULT ('r' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
name TEXT DEFAULT '' NOT NULL,
|
||||
size NUMERIC DEFAULT 0 NOT NULL,
|
||||
ticket TEXT DEFAULT '' NOT NULL,
|
||||
updated TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL
|
||||
);
|
||||
CREATE TABLE IF NOT EXISTS features
|
||||
(
|
||||
created TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL,
|
||||
id TEXT PRIMARY KEY DEFAULT ('r' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
name TEXT DEFAULT '' NOT NULL,
|
||||
updated TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL
|
||||
);
|
||||
CREATE UNIQUE INDEX IF NOT EXISTS unique_name ON features (name);
|
||||
|
||||
CREATE VIEW IF NOT EXISTS sidebar AS
|
||||
SELECT types.id as id,
|
||||
types.singular as singular,
|
||||
types.plural as plural,
|
||||
types.icon as icon,
|
||||
(SELECT COUNT(tickets.id) FROM tickets WHERE tickets.type = types.id AND tickets.open = true) as count
|
||||
FROM types
|
||||
ORDER BY types.plural;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS reactions
|
||||
(
|
||||
action TEXT DEFAULT '' NOT NULL,
|
||||
actiondata JSON DEFAULT NULL,
|
||||
created TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL,
|
||||
id TEXT PRIMARY KEY DEFAULT ('r' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
name TEXT DEFAULT '' NOT NULL,
|
||||
trigger TEXT DEFAULT '' NOT NULL,
|
||||
triggerdata JSON DEFAULT NULL,
|
||||
updated TEXT DEFAULT (strftime('%Y-%m-%d %H:%M:%fZ')) NOT NULL
|
||||
);
|
||||
|
||||
CREATE VIEW IF NOT EXISTS ticket_search AS
|
||||
SELECT tickets.id,
|
||||
tickets.name,
|
||||
tickets.created,
|
||||
tickets.description,
|
||||
tickets.open,
|
||||
tickets.type,
|
||||
tickets.state,
|
||||
users.name as owner_name,
|
||||
group_concat(comments.message
|
||||
) as comment_messages,
|
||||
group_concat(files.name
|
||||
) as file_names,
|
||||
group_concat(links.name
|
||||
) as link_names,
|
||||
group_concat(links.url
|
||||
) as link_urls,
|
||||
group_concat(tasks.name
|
||||
) as task_names,
|
||||
group_concat(timeline.message
|
||||
) as timeline_messages
|
||||
FROM tickets
|
||||
LEFT JOIN comments ON comments.ticket = tickets.id
|
||||
LEFT JOIN files ON files.ticket = tickets.id
|
||||
LEFT JOIN links ON links.ticket = tickets.id
|
||||
LEFT JOIN tasks ON tasks.ticket = tickets.id
|
||||
LEFT JOIN timeline ON timeline.ticket = tickets.id
|
||||
LEFT JOIN users ON users.id = tickets.owner
|
||||
GROUP BY tickets.id;
|
||||
|
||||
CREATE VIEW IF NOT EXISTS dashboard_counts AS
|
||||
SELECT id, count
|
||||
FROM (SELECT 'users' as id,
|
||||
COUNT(users.id
|
||||
) as count
|
||||
FROM users
|
||||
UNION
|
||||
SELECT 'tickets' as id,
|
||||
COUNT(tickets.id
|
||||
) as count
|
||||
FROM tickets
|
||||
UNION
|
||||
SELECT 'tasks' as id,
|
||||
COUNT(tasks.id
|
||||
) as count
|
||||
FROM tasks
|
||||
UNION
|
||||
SELECT 'reactions' as id,
|
||||
COUNT(reactions.id
|
||||
) as count
|
||||
FROM reactions) as counts;
|
||||
390
app/database/migrations/001_create_tables.up.sql
Normal file
390
app/database/migrations/001_create_tables.up.sql
Normal file
@@ -0,0 +1,390 @@
|
||||
DROP TABLE _migrations;
|
||||
DROP TABLE _collections;
|
||||
DROP TABLE _externalauths;
|
||||
DROP VIEW sidebar;
|
||||
DROP VIEW ticket_search;
|
||||
DROP VIEW dashboard_counts;
|
||||
|
||||
--- _params
|
||||
|
||||
CREATE TABLE new_params
|
||||
(
|
||||
key TEXT PRIMARY KEY NOT NULL,
|
||||
value JSON
|
||||
);
|
||||
|
||||
INSERT INTO new_params
|
||||
(key, value)
|
||||
SELECT key, value
|
||||
FROM _params;
|
||||
|
||||
DROP TABLE _params;
|
||||
ALTER TABLE new_params
|
||||
RENAME TO _params;
|
||||
|
||||
--- users
|
||||
|
||||
CREATE TABLE new_users
|
||||
(
|
||||
id TEXT PRIMARY KEY DEFAULT ('u' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
username TEXT NOT NULL,
|
||||
passwordHash TEXT NOT NULL,
|
||||
tokenKey TEXT NOT NULL,
|
||||
active BOOLEAN NOT NULL,
|
||||
name TEXT,
|
||||
email TEXT,
|
||||
avatar TEXT,
|
||||
lastresetsentat DATETIME,
|
||||
lastverificationsentat DATETIME,
|
||||
admin BOOLEAN NOT NULL,
|
||||
created DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
updated DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL
|
||||
);
|
||||
|
||||
INSERT INTO new_users
|
||||
(avatar, email, id, lastresetsentat, lastverificationsentat, name, passwordHash, tokenKey, username, active, admin,
|
||||
created,
|
||||
updated)
|
||||
SELECT avatar,
|
||||
email,
|
||||
id,
|
||||
lastResetSentAt,
|
||||
lastVerificationSentAt,
|
||||
name,
|
||||
passwordHash,
|
||||
tokenKey,
|
||||
username,
|
||||
verified,
|
||||
false,
|
||||
created,
|
||||
updated
|
||||
FROM users;
|
||||
|
||||
INSERT INTO new_users
|
||||
(avatar, email, id, lastresetsentat, lastverificationsentat, name, passwordHash, tokenKey, username, active, admin,
|
||||
created,
|
||||
updated)
|
||||
SELECT avatar,
|
||||
email,
|
||||
id,
|
||||
lastResetSentAt,
|
||||
'',
|
||||
email,
|
||||
passwordHash,
|
||||
tokenKey,
|
||||
id,
|
||||
true,
|
||||
true,
|
||||
created,
|
||||
updated
|
||||
FROM _admins;
|
||||
|
||||
DROP TABLE users;
|
||||
DROP TABLE _admins;
|
||||
ALTER TABLE new_users
|
||||
RENAME TO users;
|
||||
|
||||
--- webhooks
|
||||
|
||||
CREATE TABLE new_webhooks
|
||||
(
|
||||
id TEXT PRIMARY KEY DEFAULT ('w' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
collection TEXT NOT NULL,
|
||||
destination TEXT NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
created DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
updated DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL
|
||||
);
|
||||
|
||||
INSERT INTO new_webhooks
|
||||
(collection, destination, id, name, created, updated)
|
||||
SELECT collection, destination, id, name, datetime(created), datetime(updated)
|
||||
FROM webhooks;
|
||||
|
||||
DROP TABLE webhooks;
|
||||
ALTER TABLE new_webhooks
|
||||
RENAME TO webhooks;
|
||||
|
||||
--- types
|
||||
|
||||
CREATE TABLE new_types
|
||||
(
|
||||
id TEXT PRIMARY KEY DEFAULT ('y' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
icon TEXT,
|
||||
singular TEXT NOT NULL,
|
||||
plural TEXT NOT NULL,
|
||||
schema JSON,
|
||||
created DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
updated DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL
|
||||
);
|
||||
|
||||
INSERT INTO new_types
|
||||
(id, icon, singular, plural, schema, created, updated)
|
||||
SELECT id, icon, singular, plural, schema, created, updated
|
||||
FROM types;
|
||||
|
||||
DROP TABLE types;
|
||||
ALTER TABLE new_types
|
||||
RENAME TO types;
|
||||
|
||||
--- ticket
|
||||
|
||||
CREATE TABLE new_tickets
|
||||
(
|
||||
id TEXT PRIMARY KEY DEFAULT ('t' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
type TEXT NOT NULL,
|
||||
owner TEXT,
|
||||
name TEXT NOT NULL,
|
||||
description TEXT NOT NULL,
|
||||
open BOOLEAN NOT NULL,
|
||||
resolution TEXT,
|
||||
schema JSON,
|
||||
state JSON,
|
||||
created DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
updated DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
|
||||
FOREIGN KEY (type) REFERENCES types (id) ON DELETE SET NULL,
|
||||
FOREIGN KEY (owner) REFERENCES users (id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
INSERT INTO new_tickets
|
||||
(id, name, description, open, owner, resolution, schema, state, type, created, updated)
|
||||
SELECT id,
|
||||
name,
|
||||
description,
|
||||
open,
|
||||
owner,
|
||||
resolution,
|
||||
schema,
|
||||
state,
|
||||
type,
|
||||
created,
|
||||
updated
|
||||
FROM tickets;
|
||||
|
||||
DROP TABLE tickets;
|
||||
ALTER TABLE new_tickets
|
||||
RENAME TO tickets;
|
||||
|
||||
--- tasks
|
||||
|
||||
CREATE TABLE new_tasks
|
||||
(
|
||||
id TEXT PRIMARY KEY DEFAULT ('t' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
ticket TEXT NOT NULL,
|
||||
owner TEXT,
|
||||
name TEXT NOT NULL,
|
||||
open BOOLEAN NOT NULL,
|
||||
created DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
updated DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
|
||||
FOREIGN KEY (ticket) REFERENCES tickets (id) ON DELETE CASCADE,
|
||||
FOREIGN KEY (owner) REFERENCES users (id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
INSERT INTO new_tasks
|
||||
(id, ticket, owner, name, open, created, updated)
|
||||
SELECT id, ticket, owner, name, open, created, updated
|
||||
FROM tasks;
|
||||
DROP TABLE tasks;
|
||||
ALTER TABLE new_tasks
|
||||
RENAME TO tasks;
|
||||
|
||||
--- comments
|
||||
|
||||
CREATE TABLE new_comments
|
||||
(
|
||||
id TEXT PRIMARY KEY DEFAULT ('c' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
ticket TEXT NOT NULL,
|
||||
author TEXT NOT NULL,
|
||||
message TEXT NOT NULL,
|
||||
created DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
updated DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
|
||||
FOREIGN KEY (ticket) REFERENCES tickets (id) ON DELETE CASCADE,
|
||||
FOREIGN KEY (author) REFERENCES users (id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
INSERT INTO new_comments
|
||||
(id, ticket, author, message, created, updated)
|
||||
SELECT id, ticket, author, message, created, updated
|
||||
FROM comments;
|
||||
DROP TABLE comments;
|
||||
ALTER TABLE new_comments
|
||||
RENAME TO comments;
|
||||
|
||||
--- timeline
|
||||
|
||||
CREATE TABLE new_timeline
|
||||
(
|
||||
id TEXT PRIMARY KEY DEFAULT ('h' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
ticket TEXT NOT NULL,
|
||||
message TEXT NOT NULL,
|
||||
time DATETIME NOT NULL,
|
||||
created DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
updated DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
|
||||
FOREIGN KEY (ticket) REFERENCES tickets (id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
INSERT INTO new_timeline
|
||||
(id, ticket, message, time, created, updated)
|
||||
SELECT id, ticket, message, time, created, updated
|
||||
FROM timeline;
|
||||
|
||||
DROP TABLE timeline;
|
||||
ALTER TABLE new_timeline
|
||||
RENAME TO timeline;
|
||||
|
||||
--- links
|
||||
|
||||
CREATE TABLE new_links
|
||||
(
|
||||
id TEXT PRIMARY KEY DEFAULT ('l' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
ticket TEXT NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
url TEXT NOT NULL,
|
||||
created DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
updated DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
|
||||
FOREIGN KEY (ticket) REFERENCES tickets (id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
INSERT INTO new_links
|
||||
(id, ticket, name, url, created, updated)
|
||||
SELECT id, ticket, name, url, datetime(created), datetime(updated)
|
||||
FROM links;
|
||||
DROP TABLE links;
|
||||
ALTER TABLE new_links
|
||||
RENAME TO links;
|
||||
|
||||
--- files
|
||||
|
||||
CREATE TABLE new_files
|
||||
(
|
||||
id TEXT PRIMARY KEY DEFAULT ('b' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
ticket TEXT NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
blob TEXT NOT NULL,
|
||||
size NUMERIC NOT NULL,
|
||||
created DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
updated DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
|
||||
FOREIGN KEY (ticket) REFERENCES tickets (id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
INSERT INTO new_files
|
||||
(id, name, blob, size, ticket, created, updated)
|
||||
SELECT id, name, blob, size, ticket, created, updated
|
||||
FROM files;
|
||||
DROP TABLE files;
|
||||
ALTER TABLE new_files
|
||||
RENAME TO files;
|
||||
|
||||
--- features
|
||||
|
||||
CREATE TABLE new_features
|
||||
(
|
||||
key TEXT PRIMARY KEY NOT NULL
|
||||
);
|
||||
|
||||
INSERT INTO new_features
|
||||
(key)
|
||||
SELECT name
|
||||
FROM features;
|
||||
|
||||
DROP TABLE features;
|
||||
ALTER TABLE new_features
|
||||
RENAME TO features;
|
||||
|
||||
--- reactions
|
||||
|
||||
CREATE TABLE new_reactions
|
||||
(
|
||||
id TEXT PRIMARY KEY DEFAULT ('r' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
action TEXT NOT NULL,
|
||||
actiondata JSON NOT NULL,
|
||||
trigger TEXT NOT NULL,
|
||||
triggerdata JSON NOT NULL,
|
||||
created DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
updated DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL
|
||||
);
|
||||
|
||||
INSERT INTO new_reactions
|
||||
(id, name, action, actiondata, trigger, triggerdata, created, updated)
|
||||
SELECT id,
|
||||
name,
|
||||
action,
|
||||
actionData,
|
||||
trigger,
|
||||
triggerData,
|
||||
created,
|
||||
updated
|
||||
FROM reactions;
|
||||
DROP TABLE reactions;
|
||||
ALTER TABLE new_reactions
|
||||
RENAME TO reactions;
|
||||
|
||||
--- views
|
||||
|
||||
CREATE VIEW sidebar AS
|
||||
SELECT types.id as id,
|
||||
types.singular as singular,
|
||||
types.plural as plural,
|
||||
types.icon as icon,
|
||||
(SELECT COUNT(tickets.id) FROM tickets WHERE tickets.type = types.id AND tickets.open = true) as count
|
||||
FROM types
|
||||
ORDER BY types.plural;
|
||||
|
||||
CREATE VIEW ticket_search AS
|
||||
SELECT tickets.id,
|
||||
tickets.name,
|
||||
tickets.created,
|
||||
tickets.description,
|
||||
tickets.open,
|
||||
tickets.type,
|
||||
tickets.state,
|
||||
users.name as owner_name,
|
||||
group_concat(comments.message
|
||||
) as comment_messages,
|
||||
group_concat(files.name
|
||||
) as file_names,
|
||||
group_concat(links.name
|
||||
) as link_names,
|
||||
group_concat(links.url
|
||||
) as link_urls,
|
||||
group_concat(tasks.name
|
||||
) as task_names,
|
||||
group_concat(timeline.message
|
||||
) as timeline_messages
|
||||
FROM tickets
|
||||
LEFT JOIN comments ON comments.ticket = tickets.id
|
||||
LEFT JOIN files ON files.ticket = tickets.id
|
||||
LEFT JOIN links ON links.ticket = tickets.id
|
||||
LEFT JOIN tasks ON tasks.ticket = tickets.id
|
||||
LEFT JOIN timeline ON timeline.ticket = tickets.id
|
||||
LEFT JOIN users ON users.id = tickets.owner
|
||||
GROUP BY tickets.id;
|
||||
|
||||
CREATE VIEW dashboard_counts AS
|
||||
SELECT id, count
|
||||
FROM (SELECT 'users' as id,
|
||||
COUNT(users.id
|
||||
) as count
|
||||
FROM users
|
||||
UNION
|
||||
SELECT 'tickets' as id,
|
||||
COUNT(tickets.id
|
||||
) as count
|
||||
FROM tickets
|
||||
UNION
|
||||
SELECT 'tasks' as id,
|
||||
COUNT(tasks.id
|
||||
) as count
|
||||
FROM tasks
|
||||
UNION
|
||||
SELECT 'reactions' as id,
|
||||
COUNT(reactions.id
|
||||
) as count
|
||||
FROM reactions) as counts;
|
||||
5
app/database/migrations/002_create_defaultdata.up.sql
Normal file
5
app/database/migrations/002_create_defaultdata.up.sql
Normal file
@@ -0,0 +1,5 @@
|
||||
INSERT OR IGNORE INTO types (id, singular, plural, icon, schema) VALUES ('alert', 'Alert', 'Alerts', 'AlertTriangle', '{"type": "object", "properties": { "severity": { "title": "Severity", "enum": ["Low", "Medium", "High"]}}, "required": ["severity"]}');
|
||||
INSERT OR IGNORE INTO types (id, singular, plural, icon, schema) VALUES ('incident', 'Incident', 'Incidents', 'Flame', '{"type": "object", "properties": { "severity": { "title": "Severity", "enum": ["Low", "Medium", "High"]}}, "required": ["severity"]}');
|
||||
INSERT OR IGNORE INTO types (id, singular, plural, icon, schema) VALUES ('vulnerability', 'Vulnerability', 'Vulnerabilities', 'Bug', '{"type": "object", "properties": { "severity": { "title": "Severity", "enum": ["Low", "Medium", "High"]}}, "required": ["severity"]}');
|
||||
|
||||
INSERT OR IGNORE INTO users (id, name, username, passwordHash, tokenKey, active, admin) VALUES ('system', 'System', 'system', '', lower(hex(randomblob(26))), true, true);
|
||||
82
app/database/migrations/003_create_groups.up.sql
Normal file
82
app/database/migrations/003_create_groups.up.sql
Normal file
@@ -0,0 +1,82 @@
|
||||
CREATE TABLE groups
|
||||
(
|
||||
id TEXT PRIMARY KEY DEFAULT ('g' || lower(hex(randomblob(7)))) NOT NULL,
|
||||
name TEXT UNIQUE NOT NULL,
|
||||
permissions TEXT NOT NULL, -- JSON array string like '["read:article","write:article"]'
|
||||
created DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
updated DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL
|
||||
);
|
||||
|
||||
CREATE TABLE user_groups
|
||||
(
|
||||
user_id TEXT NOT NULL,
|
||||
group_id TEXT NOT NULL,
|
||||
PRIMARY KEY (user_id, group_id),
|
||||
FOREIGN KEY (user_id) REFERENCES users (id) ON DELETE CASCADE,
|
||||
FOREIGN KEY (group_id) REFERENCES groups (id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE TABLE group_inheritance
|
||||
(
|
||||
parent_group_id TEXT NOT NULL,
|
||||
child_group_id TEXT NOT NULL,
|
||||
PRIMARY KEY (parent_group_id, child_group_id),
|
||||
FOREIGN KEY (parent_group_id) REFERENCES groups (id) ON DELETE CASCADE,
|
||||
FOREIGN KEY (child_group_id) REFERENCES groups (id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE VIEW group_effective_groups AS
|
||||
WITH RECURSIVE all_groups(child_group_id, parent_group_id, group_type)
|
||||
AS (SELECT rr.child_group_id, rr.parent_group_id, 'direct' AS group_type
|
||||
FROM group_inheritance rr
|
||||
UNION
|
||||
SELECT ar.child_group_id, ri.parent_group_id, 'indirect' AS group_type
|
||||
FROM all_groups ar
|
||||
JOIN group_inheritance ri ON ri.child_group_id = ar.parent_group_id)
|
||||
SELECT child_group_id, parent_group_id, group_type
|
||||
FROM all_groups;
|
||||
|
||||
CREATE VIEW group_effective_permissions AS
|
||||
SELECT re.parent_group_id, CAST(json_each.value AS TEXT) AS permission
|
||||
FROM group_effective_groups re
|
||||
JOIN groups r ON r.id = re.child_group_id, json_each(r.permissions);
|
||||
|
||||
CREATE VIEW user_effective_groups AS
|
||||
WITH RECURSIVE all_groups(user_id, group_id, group_type) AS (
|
||||
-- Direct groups
|
||||
SELECT ur.user_id, ur.group_id, 'direct' AS group_type
|
||||
FROM user_groups ur
|
||||
|
||||
UNION
|
||||
|
||||
-- Inherited groups
|
||||
SELECT ar.user_id, ri.child_group_id, 'indirect' AS group_type
|
||||
FROM all_groups ar
|
||||
JOIN group_inheritance ri ON ri.parent_group_id = ar.group_id)
|
||||
SELECT user_id,
|
||||
group_id,
|
||||
group_type
|
||||
FROM all_groups;
|
||||
|
||||
CREATE VIEW user_effective_permissions AS
|
||||
SELECT DISTINCT uer.user_id,
|
||||
CAST(json_each.value AS TEXT) AS permission
|
||||
FROM user_effective_groups uer
|
||||
JOIN groups r ON r.id = uer.group_id, json_each(r.permissions);
|
||||
|
||||
INSERT INTO groups (id, name, permissions)
|
||||
VALUES ('analyst', 'Analyst', '["type:read", "file:read", "ticket:read", "ticket:write", "user:read", "group:read"]'),
|
||||
('admin', 'Admin', '["admin"]');
|
||||
|
||||
INSERT INTO user_groups (user_id, group_id)
|
||||
SELECT id, 'analyst'
|
||||
FROM users
|
||||
WHERE NOT admin;
|
||||
|
||||
INSERT INTO user_groups (user_id, group_id)
|
||||
SELECT id, 'admin'
|
||||
FROM users
|
||||
WHERE admin;
|
||||
|
||||
ALTER TABLE users
|
||||
DROP COLUMN admin;
|
||||
6
app/database/migrations/migrations.go
Normal file
6
app/database/migrations/migrations.go
Normal file
@@ -0,0 +1,6 @@
|
||||
package migrations
|
||||
|
||||
import "embed"
|
||||
|
||||
//go:embed *.sql
|
||||
var Migrations embed.FS
|
||||
52
app/database/paginate.go
Normal file
52
app/database/paginate.go
Normal file
@@ -0,0 +1,52 @@
|
||||
package database
|
||||
|
||||
import (
|
||||
"context"
|
||||
"database/sql"
|
||||
"errors"
|
||||
)
|
||||
|
||||
func Paginate(ctx context.Context, f func(ctx context.Context, offset, limit int64) (nextPage bool, err error)) error {
|
||||
const pageSize int64 = 100
|
||||
|
||||
for i := range int64(1000) {
|
||||
nextPage, err := f(ctx, i*pageSize, pageSize)
|
||||
if err != nil {
|
||||
if errors.Is(err, sql.ErrNoRows) {
|
||||
// No more features to process, exit the loop
|
||||
return nil
|
||||
}
|
||||
|
||||
return err
|
||||
}
|
||||
|
||||
if !nextPage {
|
||||
return nil
|
||||
}
|
||||
}
|
||||
|
||||
return errors.New("pagination limit reached, too many pages")
|
||||
}
|
||||
|
||||
func PaginateItems[T any](ctx context.Context, f func(ctx context.Context, offset, limit int64) (items []T, err error)) ([]T, error) {
|
||||
var allItems []T
|
||||
|
||||
if err := Paginate(ctx, func(ctx context.Context, offset, limit int64) (nextPage bool, err error) {
|
||||
items, err := f(ctx, offset, limit)
|
||||
if err != nil {
|
||||
return false, err
|
||||
}
|
||||
|
||||
if len(items) == 0 {
|
||||
return false, nil
|
||||
}
|
||||
|
||||
allItems = append(allItems, items...)
|
||||
|
||||
return true, nil
|
||||
}); err != nil {
|
||||
return nil, err
|
||||
}
|
||||
|
||||
return allItems, nil
|
||||
}
|
||||
97
app/database/paginate_test.go
Normal file
97
app/database/paginate_test.go
Normal file
@@ -0,0 +1,97 @@
|
||||
package database
|
||||
|
||||
import (
|
||||
"context"
|
||||
"database/sql"
|
||||
"errors"
|
||||
"testing"
|
||||
|
||||
"github.com/stretchr/testify/assert"
|
||||
"github.com/stretchr/testify/require"
|
||||
)
|
||||
|
||||
func TestPaginate_AllPages(t *testing.T) {
|
||||
t.Parallel()
|
||||
|
||||
calls := 0
|
||||
err := Paginate(t.Context(), func(_ context.Context, _, _ int64) (bool, error) {
|
||||
calls++
|
||||
if calls < 3 {
|
||||
return true, nil
|
||||
}
|
||||
|
||||
return false, nil
|
||||
})
|
||||
require.NoError(t, err, "expected no error")
|
||||
assert.Equal(t, 3, calls, "expected 3 calls")
|
||||
}
|
||||
|
||||
func TestPaginate_EarlyStop(t *testing.T) {
|
||||
t.Parallel()
|
||||
|
||||
calls := 0
|
||||
err := Paginate(t.Context(), func(_ context.Context, _, _ int64) (bool, error) {
|
||||
calls++
|
||||
|
||||
return false, nil
|
||||
})
|
||||
require.NoError(t, err, "expected no error")
|
||||
assert.Equal(t, 1, calls, "expected 1 call")
|
||||
}
|
||||
|
||||
func TestPaginate_Error(t *testing.T) {
|
||||
t.Parallel()
|
||||
|
||||
errTest := errors.New("fail")
|
||||
err := Paginate(t.Context(), func(_ context.Context, _, _ int64) (bool, error) {
|
||||
return false, errTest
|
||||
})
|
||||
assert.ErrorIs(t, err, errTest, "expected error")
|
||||
}
|
||||
|
||||
func TestPaginate_NoRows(t *testing.T) {
|
||||
t.Parallel()
|
||||
|
||||
err := Paginate(t.Context(), func(_ context.Context, _, _ int64) (bool, error) {
|
||||
return false, sql.ErrNoRows
|
||||
})
|
||||
require.NoError(t, err, "expected no error")
|
||||
}
|
||||
|
||||
func TestPaginateItems(t *testing.T) {
|
||||
t.Parallel()
|
||||
|
||||
calls := 0
|
||||
f := func(_ context.Context, offset, _ int64) ([]int, error) {
|
||||
calls++
|
||||
|
||||
if offset >= 100 {
|
||||
return nil, sql.ErrNoRows
|
||||
}
|
||||
|
||||
return []int{1}, nil
|
||||
}
|
||||
items, err := PaginateItems(t.Context(), f)
|
||||
require.NoError(t, err, "expected no error")
|
||||
assert.Equal(t, []int{1}, items, "expected items to match")
|
||||
assert.Equal(t, 2, calls, "expected 2 calls")
|
||||
}
|
||||
|
||||
func TestPaginateItemsLarge(t *testing.T) {
|
||||
t.Parallel()
|
||||
|
||||
calls := 0
|
||||
f := func(_ context.Context, offset, _ int64) ([]int, error) {
|
||||
calls++
|
||||
|
||||
if offset >= 200 {
|
||||
return nil, sql.ErrNoRows
|
||||
}
|
||||
|
||||
return []int{1}, nil
|
||||
}
|
||||
items, err := PaginateItems(t.Context(), f)
|
||||
require.NoError(t, err, "expected no error")
|
||||
assert.Equal(t, []int{1, 1}, items, "expected items to match")
|
||||
assert.Equal(t, 3, calls, "expected 3 calls")
|
||||
}
|
||||
285
app/database/read.sql
Normal file
285
app/database/read.sql
Normal file
@@ -0,0 +1,285 @@
|
||||
-- name: Param :one
|
||||
SELECT *
|
||||
FROM _params
|
||||
WHERE _params.key = @key;
|
||||
|
||||
-------------------------------------------------------------------
|
||||
|
||||
-- name: Ticket :one
|
||||
SELECT tickets.*, users.name as owner_name, types.singular as type_singular, types.plural as type_plural
|
||||
FROM tickets
|
||||
LEFT JOIN users ON users.id = tickets.owner
|
||||
LEFT JOIN types ON types.id = tickets.type
|
||||
WHERE tickets.id = @id;
|
||||
|
||||
-- name: ListTickets :many
|
||||
SELECT tickets.*,
|
||||
users.name as owner_name,
|
||||
types.singular as type_singular,
|
||||
types.plural as type_plural,
|
||||
COUNT(*) OVER () as total_count
|
||||
FROM tickets
|
||||
LEFT JOIN users ON users.id = tickets.owner
|
||||
LEFT JOIN types ON types.id = tickets.type
|
||||
ORDER BY tickets.created DESC
|
||||
LIMIT @limit OFFSET @offset;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: GetComment :one
|
||||
SELECT comments.*, users.name as author_name
|
||||
FROM comments
|
||||
LEFT JOIN users ON users.id = comments.author
|
||||
WHERE comments.id = @id;
|
||||
|
||||
-- name: ListComments :many
|
||||
SELECT comments.*, users.name as author_name, COUNT(*) OVER () as total_count
|
||||
FROM comments
|
||||
LEFT JOIN users ON users.id = comments.author
|
||||
WHERE ticket = @ticket
|
||||
OR @ticket = ''
|
||||
ORDER BY comments.created DESC
|
||||
LIMIT @limit OFFSET @offset;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: GetFeature :one
|
||||
SELECT *
|
||||
FROM features
|
||||
WHERE key = @key;
|
||||
|
||||
-- name: ListFeatures :many
|
||||
SELECT features.*, COUNT(*) OVER () as total_count
|
||||
FROM features
|
||||
ORDER BY features.key DESC
|
||||
LIMIT @limit OFFSET @offset;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: GetFile :one
|
||||
SELECT *
|
||||
FROM files
|
||||
WHERE id = @id;
|
||||
|
||||
-- name: ListFiles :many
|
||||
SELECT files.*, COUNT(*) OVER () as total_count
|
||||
FROM files
|
||||
WHERE ticket = @ticket
|
||||
OR @ticket = ''
|
||||
ORDER BY files.created DESC
|
||||
LIMIT @limit OFFSET @offset;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: GetLink :one
|
||||
SELECT *
|
||||
FROM links
|
||||
WHERE id = @id;
|
||||
|
||||
-- name: ListLinks :many
|
||||
SELECT links.*, COUNT(*) OVER () as total_count
|
||||
FROM links
|
||||
WHERE ticket = @ticket
|
||||
OR @ticket = ''
|
||||
ORDER BY links.created DESC
|
||||
LIMIT @limit OFFSET @offset;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: GetReaction :one
|
||||
SELECT *
|
||||
FROM reactions
|
||||
WHERE id = @id;
|
||||
|
||||
-- name: ListReactions :many
|
||||
SELECT reactions.*, COUNT(*) OVER () as total_count
|
||||
FROM reactions
|
||||
ORDER BY reactions.created DESC
|
||||
LIMIT @limit OFFSET @offset;
|
||||
|
||||
-- name: ListReactionsByTrigger :many
|
||||
SELECT reactions.*, COUNT(*) OVER () as total_count
|
||||
FROM reactions
|
||||
WHERE trigger = @trigger
|
||||
ORDER BY reactions.created DESC
|
||||
LIMIT @limit OFFSET @offset;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: GetTask :one
|
||||
SELECT tasks.*, users.name as owner_name, tickets.name as ticket_name, tickets.type as ticket_type
|
||||
FROM tasks
|
||||
LEFT JOIN users ON users.id = tasks.owner
|
||||
LEFT JOIN tickets ON tickets.id = tasks.ticket
|
||||
WHERE tasks.id = @id;
|
||||
|
||||
-- name: ListTasks :many
|
||||
SELECT tasks.*,
|
||||
users.name as owner_name,
|
||||
tickets.name as ticket_name,
|
||||
tickets.type as ticket_type,
|
||||
COUNT(*) OVER () as total_count
|
||||
FROM tasks
|
||||
LEFT JOIN users ON users.id = tasks.owner
|
||||
LEFT JOIN tickets ON tickets.id = tasks.ticket
|
||||
WHERE ticket = @ticket
|
||||
OR @ticket = ''
|
||||
ORDER BY tasks.created DESC
|
||||
LIMIT @limit OFFSET @offset;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: GetTimeline :one
|
||||
SELECT *
|
||||
FROM timeline
|
||||
WHERE id = @id;
|
||||
|
||||
-- name: ListTimeline :many
|
||||
SELECT timeline.*, COUNT(*) OVER () as total_count
|
||||
FROM timeline
|
||||
WHERE ticket = @ticket
|
||||
OR @ticket = ''
|
||||
ORDER BY timeline.created DESC
|
||||
LIMIT @limit OFFSET @offset;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: GetType :one
|
||||
SELECT *
|
||||
FROM types
|
||||
WHERE id = @id;
|
||||
|
||||
-- name: ListTypes :many
|
||||
SELECT types.*, COUNT(*) OVER () as total_count
|
||||
FROM types
|
||||
ORDER BY created DESC
|
||||
LIMIT @limit OFFSET @offset;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: GetUser :one
|
||||
SELECT *
|
||||
FROM users
|
||||
WHERE id = @id;
|
||||
|
||||
-- name: UserByUserName :one
|
||||
SELECT *
|
||||
FROM users
|
||||
WHERE username = @username;
|
||||
|
||||
-- name: UserByEmail :one
|
||||
SELECT *
|
||||
FROM users
|
||||
WHERE email = @email;
|
||||
|
||||
-- name: SystemUser :one
|
||||
SELECT *
|
||||
FROM users
|
||||
WHERE id = 'system';
|
||||
|
||||
-- name: ListUsers :many
|
||||
SELECT users.*, COUNT(*) OVER () as total_count
|
||||
FROM users
|
||||
WHERE id != 'system'
|
||||
ORDER BY users.created DESC
|
||||
LIMIT @limit OFFSET @offset;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: GetWebhook :one
|
||||
SELECT *
|
||||
FROM webhooks
|
||||
WHERE id = @id;
|
||||
|
||||
-- name: ListWebhooks :many
|
||||
SELECT webhooks.*, COUNT(*) OVER () as total_count
|
||||
FROM webhooks
|
||||
ORDER BY created DESC
|
||||
LIMIT @limit OFFSET @offset;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: GetDashboardCounts :many
|
||||
SELECT *
|
||||
FROM dashboard_counts;
|
||||
|
||||
-- name: GetSidebar :many
|
||||
SELECT *
|
||||
FROM sidebar;
|
||||
|
||||
-- name: SearchTickets :many
|
||||
SELECT id,
|
||||
name,
|
||||
created,
|
||||
description,
|
||||
open,
|
||||
type,
|
||||
state,
|
||||
owner_name,
|
||||
COUNT(*) OVER () as total_count
|
||||
FROM ticket_search
|
||||
WHERE (@query = '' OR (name LIKE '%' || @query || '%'
|
||||
OR description LIKE '%' || @query || '%'
|
||||
OR comment_messages LIKE '%' || @query || '%'
|
||||
OR file_names LIKE '%' || @query || '%'
|
||||
OR link_names LIKE '%' || @query || '%'
|
||||
OR link_urls LIKE '%' || @query || '%'
|
||||
OR task_names LIKE '%' || @query || '%'
|
||||
OR timeline_messages LIKE '%' || @query || '%'))
|
||||
AND (sqlc.narg('type') IS NULL OR type = sqlc.narg('type'))
|
||||
AND (sqlc.narg('open') IS NULL OR open = sqlc.narg('open'))
|
||||
ORDER BY created DESC
|
||||
LIMIT @limit OFFSET @offset;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: GetGroup :one
|
||||
SELECT *
|
||||
FROM groups
|
||||
WHERE id = @id;
|
||||
|
||||
-- name: ListGroups :many
|
||||
SELECT g.*, COUNT(*) OVER () as total_count
|
||||
FROM groups AS g
|
||||
ORDER BY g.created DESC
|
||||
LIMIT @limit OFFSET @offset;
|
||||
|
||||
-- name: ListUserGroups :many
|
||||
SELECT g.*, uer.group_type, COUNT(*) OVER () as total_count
|
||||
FROM user_effective_groups uer
|
||||
JOIN groups AS g ON g.id = uer.group_id
|
||||
WHERE uer.user_id = @user_id
|
||||
ORDER BY g.name DESC;
|
||||
|
||||
-- name: ListGroupUsers :many
|
||||
SELECT users.*, uer.group_type
|
||||
FROM user_effective_groups uer
|
||||
JOIN users ON users.id = uer.user_id
|
||||
WHERE uer.group_id = @group_id
|
||||
ORDER BY users.name DESC;
|
||||
|
||||
-- name: ListUserPermissions :many
|
||||
SELECT user_effective_permissions.permission
|
||||
FROM user_effective_permissions
|
||||
WHERE user_id = @user_id
|
||||
ORDER BY permission;
|
||||
|
||||
-- name: ListParentGroups :many
|
||||
SELECT g.*, group_effective_groups.group_type
|
||||
FROM group_effective_groups
|
||||
JOIN groups AS g ON g.id = group_effective_groups.child_group_id
|
||||
WHERE parent_group_id = @group_id
|
||||
ORDER BY group_effective_groups.group_type;
|
||||
|
||||
-- name: ListChildGroups :many
|
||||
SELECT g.*, group_effective_groups.group_type
|
||||
FROM group_effective_groups
|
||||
JOIN groups AS g ON g.id = group_effective_groups.parent_group_id
|
||||
WHERE child_group_id = @group_id
|
||||
ORDER BY group_effective_groups.group_type;
|
||||
|
||||
-- name: ListParentPermissions :many
|
||||
SELECT group_effective_permissions.permission
|
||||
FROM group_effective_permissions
|
||||
WHERE parent_group_id = @group_id
|
||||
ORDER BY permission;
|
||||
37
app/database/sqlc.db.go.tmpl
Normal file
37
app/database/sqlc.db.go.tmpl
Normal file
@@ -0,0 +1,37 @@
|
||||
package sqlc
|
||||
|
||||
import (
|
||||
"context"
|
||||
"database/sql"
|
||||
)
|
||||
|
||||
type DBTX interface {
|
||||
ExecContext(ctx context.Context, query string, args ...interface{}) (sql.Result, error)
|
||||
PrepareContext(ctx context.Context, query string) (*sql.Stmt, error)
|
||||
QueryContext(ctx context.Context, query string, args ...interface{}) (*sql.Rows, error)
|
||||
QueryRowContext(ctx context.Context, query string, args ...interface{}) *sql.Row
|
||||
}
|
||||
|
||||
type Queries struct {
|
||||
*ReadQueries
|
||||
*WriteQueries
|
||||
ReadDB *sql.DB
|
||||
WriteDB *sql.DB
|
||||
}
|
||||
|
||||
type ReadQueries struct {
|
||||
db DBTX
|
||||
}
|
||||
|
||||
type WriteQueries struct {
|
||||
db DBTX
|
||||
}
|
||||
|
||||
func New(readDB, writeDB *sql.DB) *Queries {
|
||||
return &Queries{
|
||||
ReadQueries: &ReadQueries{db: readDB},
|
||||
WriteQueries: &WriteQueries{db: writeDB},
|
||||
ReadDB: readDB,
|
||||
WriteDB: writeDB,
|
||||
}
|
||||
}
|
||||
32
app/database/sqlc.yaml
Normal file
32
app/database/sqlc.yaml
Normal file
@@ -0,0 +1,32 @@
|
||||
version: "2"
|
||||
sql:
|
||||
- engine: "sqlite"
|
||||
queries: "read.sql"
|
||||
schema: "migrations"
|
||||
gen:
|
||||
go:
|
||||
package: "sqlc"
|
||||
out: "sqlc"
|
||||
emit_json_tags: true
|
||||
emit_pointers_for_null_types: true
|
||||
overrides:
|
||||
- { "column": "*.schema", "go_type": { "type": "[]byte" } }
|
||||
- { "column": "*.state", "go_type": { "type": "[]byte" } }
|
||||
- { "column": "reactions.actiondata", "go_type": { "type": "[]byte" } }
|
||||
- { "column": "reactions.triggerdata", "go_type": { "type": "[]byte" } }
|
||||
- { "column": "_params.value", "go_type": { "type": "[]byte" } }
|
||||
- engine: "sqlite"
|
||||
queries: "write.sql"
|
||||
schema: "migrations"
|
||||
gen:
|
||||
go:
|
||||
package: "sqlc"
|
||||
out: "sqlc"
|
||||
emit_json_tags: true
|
||||
emit_pointers_for_null_types: true
|
||||
overrides:
|
||||
- { "column": "*.schema", "go_type": { "type": "[]byte" } }
|
||||
- { "column": "*.state", "go_type": { "type": "[]byte" } }
|
||||
- { "column": "reactions.actiondata", "go_type": { "type": "[]byte" } }
|
||||
- { "column": "reactions.triggerdata", "go_type": { "type": "[]byte" } }
|
||||
- { "column": "_params.value", "go_type": { "type": "[]byte" } }
|
||||
37
app/database/sqlc/db.go
Normal file
37
app/database/sqlc/db.go
Normal file
@@ -0,0 +1,37 @@
|
||||
package sqlc
|
||||
|
||||
import (
|
||||
"context"
|
||||
"database/sql"
|
||||
)
|
||||
|
||||
type DBTX interface {
|
||||
ExecContext(ctx context.Context, query string, args ...interface{}) (sql.Result, error)
|
||||
PrepareContext(ctx context.Context, query string) (*sql.Stmt, error)
|
||||
QueryContext(ctx context.Context, query string, args ...interface{}) (*sql.Rows, error)
|
||||
QueryRowContext(ctx context.Context, query string, args ...interface{}) *sql.Row
|
||||
}
|
||||
|
||||
type Queries struct {
|
||||
*ReadQueries
|
||||
*WriteQueries
|
||||
ReadDB *sql.DB
|
||||
WriteDB *sql.DB
|
||||
}
|
||||
|
||||
type ReadQueries struct {
|
||||
db DBTX
|
||||
}
|
||||
|
||||
type WriteQueries struct {
|
||||
db DBTX
|
||||
}
|
||||
|
||||
func New(readDB, writeDB *sql.DB) *Queries {
|
||||
return &Queries{
|
||||
ReadQueries: &ReadQueries{db: readDB},
|
||||
WriteQueries: &WriteQueries{db: writeDB},
|
||||
ReadDB: readDB,
|
||||
WriteDB: writeDB,
|
||||
}
|
||||
}
|
||||
194
app/database/sqlc/models.go
Normal file
194
app/database/sqlc/models.go
Normal file
@@ -0,0 +1,194 @@
|
||||
// Code generated by sqlc. DO NOT EDIT.
|
||||
// versions:
|
||||
// sqlc v1.29.0
|
||||
|
||||
package sqlc
|
||||
|
||||
import (
|
||||
"time"
|
||||
)
|
||||
|
||||
type Comment struct {
|
||||
ID string `json:"id"`
|
||||
Ticket string `json:"ticket"`
|
||||
Author string `json:"author"`
|
||||
Message string `json:"message"`
|
||||
Created time.Time `json:"created"`
|
||||
Updated time.Time `json:"updated"`
|
||||
}
|
||||
|
||||
type DashboardCount struct {
|
||||
ID string `json:"id"`
|
||||
Count int64 `json:"count"`
|
||||
}
|
||||
|
||||
type Feature struct {
|
||||
Key string `json:"key"`
|
||||
}
|
||||
|
||||
type File struct {
|
||||
ID string `json:"id"`
|
||||
Ticket string `json:"ticket"`
|
||||
Name string `json:"name"`
|
||||
Blob string `json:"blob"`
|
||||
Size float64 `json:"size"`
|
||||
Created time.Time `json:"created"`
|
||||
Updated time.Time `json:"updated"`
|
||||
}
|
||||
|
||||
type Group struct {
|
||||
ID string `json:"id"`
|
||||
Name string `json:"name"`
|
||||
Permissions string `json:"permissions"`
|
||||
Created time.Time `json:"created"`
|
||||
Updated time.Time `json:"updated"`
|
||||
}
|
||||
|
||||
type GroupEffectiveGroup struct {
|
||||
ChildGroupID string `json:"child_group_id"`
|
||||
ParentGroupID string `json:"parent_group_id"`
|
||||
GroupType string `json:"group_type"`
|
||||
}
|
||||
|
||||
type GroupEffectivePermission struct {
|
||||
ParentGroupID string `json:"parent_group_id"`
|
||||
Permission string `json:"permission"`
|
||||
}
|
||||
|
||||
type GroupInheritance struct {
|
||||
ParentGroupID string `json:"parent_group_id"`
|
||||
ChildGroupID string `json:"child_group_id"`
|
||||
}
|
||||
|
||||
type Link struct {
|
||||
ID string `json:"id"`
|
||||
Ticket string `json:"ticket"`
|
||||
Name string `json:"name"`
|
||||
Url string `json:"url"`
|
||||
Created time.Time `json:"created"`
|
||||
Updated time.Time `json:"updated"`
|
||||
}
|
||||
|
||||
type Param struct {
|
||||
Key string `json:"key"`
|
||||
Value []byte `json:"value"`
|
||||
}
|
||||
|
||||
type Reaction struct {
|
||||
ID string `json:"id"`
|
||||
Name string `json:"name"`
|
||||
Action string `json:"action"`
|
||||
Actiondata []byte `json:"actiondata"`
|
||||
Trigger string `json:"trigger"`
|
||||
Triggerdata []byte `json:"triggerdata"`
|
||||
Created time.Time `json:"created"`
|
||||
Updated time.Time `json:"updated"`
|
||||
}
|
||||
|
||||
type Sidebar struct {
|
||||
ID string `json:"id"`
|
||||
Singular string `json:"singular"`
|
||||
Plural string `json:"plural"`
|
||||
Icon *string `json:"icon"`
|
||||
Count int64 `json:"count"`
|
||||
}
|
||||
|
||||
type Task struct {
|
||||
ID string `json:"id"`
|
||||
Ticket string `json:"ticket"`
|
||||
Owner *string `json:"owner"`
|
||||
Name string `json:"name"`
|
||||
Open bool `json:"open"`
|
||||
Created time.Time `json:"created"`
|
||||
Updated time.Time `json:"updated"`
|
||||
}
|
||||
|
||||
type Ticket struct {
|
||||
ID string `json:"id"`
|
||||
Type string `json:"type"`
|
||||
Owner *string `json:"owner"`
|
||||
Name string `json:"name"`
|
||||
Description string `json:"description"`
|
||||
Open bool `json:"open"`
|
||||
Resolution *string `json:"resolution"`
|
||||
Schema []byte `json:"schema"`
|
||||
State []byte `json:"state"`
|
||||
Created time.Time `json:"created"`
|
||||
Updated time.Time `json:"updated"`
|
||||
}
|
||||
|
||||
type TicketSearch struct {
|
||||
ID string `json:"id"`
|
||||
Name string `json:"name"`
|
||||
Created time.Time `json:"created"`
|
||||
Description string `json:"description"`
|
||||
Open bool `json:"open"`
|
||||
Type string `json:"type"`
|
||||
State []byte `json:"state"`
|
||||
OwnerName *string `json:"owner_name"`
|
||||
CommentMessages string `json:"comment_messages"`
|
||||
FileNames string `json:"file_names"`
|
||||
LinkNames string `json:"link_names"`
|
||||
LinkUrls string `json:"link_urls"`
|
||||
TaskNames string `json:"task_names"`
|
||||
TimelineMessages string `json:"timeline_messages"`
|
||||
}
|
||||
|
||||
type Timeline struct {
|
||||
ID string `json:"id"`
|
||||
Ticket string `json:"ticket"`
|
||||
Message string `json:"message"`
|
||||
Time time.Time `json:"time"`
|
||||
Created time.Time `json:"created"`
|
||||
Updated time.Time `json:"updated"`
|
||||
}
|
||||
|
||||
type Type struct {
|
||||
ID string `json:"id"`
|
||||
Icon *string `json:"icon"`
|
||||
Singular string `json:"singular"`
|
||||
Plural string `json:"plural"`
|
||||
Schema []byte `json:"schema"`
|
||||
Created time.Time `json:"created"`
|
||||
Updated time.Time `json:"updated"`
|
||||
}
|
||||
|
||||
type User struct {
|
||||
ID string `json:"id"`
|
||||
Username string `json:"username"`
|
||||
Passwordhash string `json:"passwordhash"`
|
||||
Tokenkey string `json:"tokenkey"`
|
||||
Active bool `json:"active"`
|
||||
Name *string `json:"name"`
|
||||
Email *string `json:"email"`
|
||||
Avatar *string `json:"avatar"`
|
||||
Lastresetsentat *time.Time `json:"lastresetsentat"`
|
||||
Lastverificationsentat *time.Time `json:"lastverificationsentat"`
|
||||
Created time.Time `json:"created"`
|
||||
Updated time.Time `json:"updated"`
|
||||
}
|
||||
|
||||
type UserEffectiveGroup struct {
|
||||
UserID string `json:"user_id"`
|
||||
GroupID string `json:"group_id"`
|
||||
GroupType string `json:"group_type"`
|
||||
}
|
||||
|
||||
type UserEffectivePermission struct {
|
||||
UserID string `json:"user_id"`
|
||||
Permission string `json:"permission"`
|
||||
}
|
||||
|
||||
type UserGroup struct {
|
||||
UserID string `json:"user_id"`
|
||||
GroupID string `json:"group_id"`
|
||||
}
|
||||
|
||||
type Webhook struct {
|
||||
ID string `json:"id"`
|
||||
Collection string `json:"collection"`
|
||||
Destination string `json:"destination"`
|
||||
Name string `json:"name"`
|
||||
Created time.Time `json:"created"`
|
||||
Updated time.Time `json:"updated"`
|
||||
}
|
||||
1592
app/database/sqlc/read.sql.go
Normal file
1592
app/database/sqlc/read.sql.go
Normal file
File diff suppressed because it is too large
Load Diff
1479
app/database/sqlc/write.sql.go
Normal file
1479
app/database/sqlc/write.sql.go
Normal file
File diff suppressed because it is too large
Load Diff
45
app/database/tables.go
Normal file
45
app/database/tables.go
Normal file
@@ -0,0 +1,45 @@
|
||||
package database
|
||||
|
||||
type Table struct {
|
||||
ID string `json:"id"`
|
||||
Name string `json:"name"`
|
||||
}
|
||||
|
||||
var (
|
||||
TicketsTable = Table{ID: "tickets", Name: "Tickets"}
|
||||
CommentsTable = Table{ID: "comments", Name: "Comments"}
|
||||
LinksTable = Table{ID: "links", Name: "Links"}
|
||||
TasksTable = Table{ID: "tasks", Name: "Tasks"}
|
||||
TimelinesTable = Table{ID: "timeline", Name: "Timeline"}
|
||||
FilesTable = Table{ID: "files", Name: "Files"}
|
||||
TypesTable = Table{ID: "types", Name: "Types"}
|
||||
UsersTable = Table{ID: "users", Name: "Users"}
|
||||
GroupsTable = Table{ID: "groups", Name: "Groups"}
|
||||
ReactionsTable = Table{ID: "reactions", Name: "Reactions"}
|
||||
WebhooksTable = Table{ID: "webhooks", Name: "Webhooks"}
|
||||
|
||||
DashboardCountsTable = Table{ID: "dashboard_counts", Name: "Dashboard Counts"}
|
||||
SidebarTable = Table{ID: "sidebar", Name: "Sidebar"}
|
||||
UserPermissionTable = Table{ID: "user_permissions", Name: "User Permissions"}
|
||||
UserGroupTable = Table{ID: "user_groups", Name: "User Groups"}
|
||||
GroupUserTable = Table{ID: "group_users", Name: "Group Users"}
|
||||
GroupPermissionTable = Table{ID: "group_permissions", Name: "Group Permissions"}
|
||||
GroupParentTable = Table{ID: "group_parents", Name: "Group Parents"}
|
||||
GroupChildTable = Table{ID: "group_children", Name: "Group Children"}
|
||||
|
||||
CreateAction = "create"
|
||||
UpdateAction = "update"
|
||||
DeleteAction = "delete"
|
||||
)
|
||||
|
||||
func Tables() []Table {
|
||||
return []Table{
|
||||
TicketsTable,
|
||||
FilesTable,
|
||||
TypesTable,
|
||||
UsersTable,
|
||||
GroupsTable,
|
||||
ReactionsTable,
|
||||
WebhooksTable,
|
||||
}
|
||||
}
|
||||
328
app/database/write.sql
Normal file
328
app/database/write.sql
Normal file
@@ -0,0 +1,328 @@
|
||||
-- name: CreateParam :exec
|
||||
INSERT INTO _params (key, value)
|
||||
VALUES (@key, @value)
|
||||
RETURNING *;
|
||||
|
||||
-- name: UpdateParam :exec
|
||||
UPDATE _params
|
||||
SET value = @value
|
||||
WHERE key = @key
|
||||
RETURNING *;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: InsertTicket :one
|
||||
INSERT INTO tickets (id, name, description, open, owner, resolution, schema, state, type, created, updated)
|
||||
VALUES (@id, @name, @description, @open, @owner, @resolution, @schema, @state, @type, @created, @updated)
|
||||
RETURNING *;
|
||||
|
||||
-- name: CreateTicket :one
|
||||
INSERT INTO tickets (name, description, open, owner, resolution, schema, state, type)
|
||||
VALUES (@name, @description, @open, @owner, @resolution, @schema, @state, @type)
|
||||
RETURNING *;
|
||||
|
||||
-- name: UpdateTicket :one
|
||||
UPDATE tickets
|
||||
SET name = coalesce(sqlc.narg('name'), name),
|
||||
description = coalesce(sqlc.narg('description'), description),
|
||||
open = coalesce(sqlc.narg('open'), open),
|
||||
owner = coalesce(sqlc.narg('owner'), owner),
|
||||
resolution = coalesce(sqlc.narg('resolution'), resolution),
|
||||
schema = coalesce(sqlc.narg('schema'), schema),
|
||||
state = coalesce(sqlc.narg('state'), state),
|
||||
type = coalesce(sqlc.narg('type'), type)
|
||||
WHERE id = @id
|
||||
RETURNING *;
|
||||
|
||||
-- name: DeleteTicket :exec
|
||||
DELETE
|
||||
FROM tickets
|
||||
WHERE id = @id;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: InsertComment :one
|
||||
INSERT INTO comments (id, author, message, ticket, created, updated)
|
||||
VALUES (@id, @author, @message, @ticket, @created, @updated)
|
||||
RETURNING *;
|
||||
|
||||
-- name: CreateComment :one
|
||||
INSERT INTO comments (author, message, ticket)
|
||||
VALUES (@author, @message, @ticket)
|
||||
RETURNING *;
|
||||
|
||||
-- name: UpdateComment :one
|
||||
UPDATE comments
|
||||
SET message = coalesce(sqlc.narg('message'), message)
|
||||
WHERE id = @id
|
||||
RETURNING *;
|
||||
|
||||
-- name: DeleteComment :exec
|
||||
DELETE
|
||||
FROM comments
|
||||
WHERE id = @id;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: CreateFeature :one
|
||||
INSERT INTO features (key)
|
||||
VALUES (@key)
|
||||
RETURNING *;
|
||||
|
||||
-- name: DeleteFeature :exec
|
||||
DELETE
|
||||
FROM features
|
||||
WHERE key = @key;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: InsertFile :one
|
||||
INSERT INTO files (id, name, blob, size, ticket, created, updated)
|
||||
VALUES (@id, @name, @blob, @size, @ticket, @created, @updated)
|
||||
RETURNING *;
|
||||
|
||||
-- name: CreateFile :one
|
||||
INSERT INTO files (name, blob, size, ticket)
|
||||
VALUES (@name, @blob, @size, @ticket)
|
||||
RETURNING *;
|
||||
|
||||
-- name: UpdateFile :one
|
||||
UPDATE files
|
||||
SET name = coalesce(sqlc.narg('name'), name),
|
||||
blob = coalesce(sqlc.narg('blob'), blob),
|
||||
size = coalesce(sqlc.narg('size'), size)
|
||||
WHERE id = @id
|
||||
RETURNING *;
|
||||
|
||||
-- name: DeleteFile :exec
|
||||
DELETE
|
||||
FROM files
|
||||
WHERE id = @id;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: InsertLink :one
|
||||
INSERT INTO links (id, name, url, ticket, created, updated)
|
||||
VALUES (@id, @name, @url, @ticket, @created, @updated)
|
||||
RETURNING *;
|
||||
|
||||
-- name: CreateLink :one
|
||||
INSERT INTO links (name, url, ticket)
|
||||
VALUES (@name, @url, @ticket)
|
||||
RETURNING *;
|
||||
|
||||
-- name: UpdateLink :one
|
||||
UPDATE links
|
||||
SET name = coalesce(sqlc.narg('name'), name),
|
||||
url = coalesce(sqlc.narg('url'), url)
|
||||
WHERE id = @id
|
||||
RETURNING *;
|
||||
|
||||
-- name: DeleteLink :exec
|
||||
DELETE
|
||||
FROM links
|
||||
WHERE id = @id;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: InsertReaction :one
|
||||
INSERT INTO reactions (id, name, action, actiondata, trigger, triggerdata, created, updated)
|
||||
VALUES (@id, @name, @action, @actiondata, @trigger, @triggerdata, @created, @updated)
|
||||
RETURNING *;
|
||||
|
||||
-- name: CreateReaction :one
|
||||
INSERT INTO reactions (name, action, actiondata, trigger, triggerdata)
|
||||
VALUES (@name, @action, @actiondata, @trigger, @triggerdata)
|
||||
RETURNING *;
|
||||
|
||||
-- name: UpdateReaction :one
|
||||
UPDATE reactions
|
||||
SET name = coalesce(sqlc.narg('name'), name),
|
||||
action = coalesce(sqlc.narg('action'), action),
|
||||
actiondata = coalesce(sqlc.narg('actiondata'), actiondata),
|
||||
trigger = coalesce(sqlc.narg('trigger'), trigger),
|
||||
triggerdata = coalesce(sqlc.narg('triggerdata'), triggerdata)
|
||||
WHERE id = @id
|
||||
RETURNING *;
|
||||
|
||||
-- name: DeleteReaction :exec
|
||||
DELETE
|
||||
FROM reactions
|
||||
WHERE id = @id;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: InsertTask :one
|
||||
INSERT INTO tasks (id, name, open, owner, ticket, created, updated)
|
||||
VALUES (@id, @name, @open, @owner, @ticket, @created, @updated)
|
||||
RETURNING *;
|
||||
|
||||
-- name: CreateTask :one
|
||||
INSERT INTO tasks (name, open, owner, ticket)
|
||||
VALUES (@name, @open, @owner, @ticket)
|
||||
RETURNING *;
|
||||
|
||||
-- name: UpdateTask :one
|
||||
UPDATE tasks
|
||||
SET name = coalesce(sqlc.narg('name'), name),
|
||||
open = coalesce(sqlc.narg('open'), open),
|
||||
owner = coalesce(sqlc.narg('owner'), owner)
|
||||
WHERE id = @id
|
||||
RETURNING *;
|
||||
|
||||
-- name: DeleteTask :exec
|
||||
DELETE
|
||||
FROM tasks
|
||||
WHERE id = @id;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: InsertTimeline :one
|
||||
INSERT INTO timeline (id, message, ticket, time, created, updated)
|
||||
VALUES (@id, @message, @ticket, @time, @created, @updated)
|
||||
RETURNING *;
|
||||
|
||||
-- name: CreateTimeline :one
|
||||
INSERT INTO timeline (message, ticket, time)
|
||||
VALUES (@message, @ticket, @time)
|
||||
RETURNING *;
|
||||
|
||||
-- name: UpdateTimeline :one
|
||||
UPDATE timeline
|
||||
SET message = coalesce(sqlc.narg('message'), message),
|
||||
time = coalesce(sqlc.narg('time'), time)
|
||||
WHERE id = @id
|
||||
RETURNING *;
|
||||
|
||||
-- name: DeleteTimeline :exec
|
||||
DELETE
|
||||
FROM timeline
|
||||
WHERE id = @id;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: InsertType :one
|
||||
INSERT INTO types (id, singular, plural, icon, schema, created, updated)
|
||||
VALUES (@id, @singular, @plural, @icon, @schema, @created, @updated)
|
||||
RETURNING *;
|
||||
|
||||
-- name: CreateType :one
|
||||
INSERT INTO types (singular, plural, icon, schema)
|
||||
VALUES (@singular, @plural, @icon, @schema)
|
||||
RETURNING *;
|
||||
|
||||
-- name: UpdateType :one
|
||||
UPDATE types
|
||||
SET singular = coalesce(sqlc.narg('singular'), singular),
|
||||
plural = coalesce(sqlc.narg('plural'), plural),
|
||||
icon = coalesce(sqlc.narg('icon'), icon),
|
||||
schema = coalesce(sqlc.narg('schema'), schema)
|
||||
WHERE id = @id
|
||||
RETURNING *;
|
||||
|
||||
-- name: DeleteType :exec
|
||||
DELETE
|
||||
FROM types
|
||||
WHERE id = @id;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: InsertUser :one
|
||||
INSERT INTO users (id, name, email, username, passwordHash, tokenKey, avatar, active, created, updated)
|
||||
VALUES (@id, @name, @email, @username, @passwordHash, @tokenKey, @avatar, @active, @created, @updated)
|
||||
RETURNING *;
|
||||
|
||||
-- name: CreateUser :one
|
||||
INSERT INTO users (name, email, username, passwordHash, tokenKey, avatar, active)
|
||||
VALUES (@name, @email, @username, @passwordHash, @tokenKey, @avatar, @active)
|
||||
RETURNING *;
|
||||
|
||||
-- name: UpdateUser :one
|
||||
UPDATE users
|
||||
SET name = coalesce(sqlc.narg('name'), name),
|
||||
email = coalesce(sqlc.narg('email'), email),
|
||||
username = coalesce(sqlc.narg('username'), username),
|
||||
passwordHash = coalesce(sqlc.narg('passwordHash'), passwordHash),
|
||||
tokenKey = coalesce(sqlc.narg('tokenKey'), tokenKey),
|
||||
avatar = coalesce(sqlc.narg('avatar'), avatar),
|
||||
active = coalesce(sqlc.narg('active'), active),
|
||||
lastResetSentAt = coalesce(sqlc.narg('lastResetSentAt'), lastResetSentAt),
|
||||
lastVerificationSentAt = coalesce(sqlc.narg('lastVerificationSentAt'), lastVerificationSentAt)
|
||||
WHERE id = @id
|
||||
AND id != 'system'
|
||||
RETURNING *;
|
||||
|
||||
-- name: DeleteUser :exec
|
||||
DELETE
|
||||
FROM users
|
||||
WHERE id = @id
|
||||
AND id != 'system';
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: InsertWebhook :one
|
||||
INSERT INTO webhooks (id, name, collection, destination, created, updated)
|
||||
VALUES (@id, @name, @collection, @destination, @created, @updated)
|
||||
RETURNING *;
|
||||
|
||||
-- name: CreateWebhook :one
|
||||
INSERT INTO webhooks (name, collection, destination)
|
||||
VALUES (@name, @collection, @destination)
|
||||
RETURNING *;
|
||||
|
||||
-- name: UpdateWebhook :one
|
||||
UPDATE webhooks
|
||||
SET name = coalesce(sqlc.narg('name'), name),
|
||||
collection = coalesce(sqlc.narg('collection'), collection),
|
||||
destination = coalesce(sqlc.narg('destination'), destination)
|
||||
WHERE id = @id
|
||||
RETURNING *;
|
||||
|
||||
-- name: DeleteWebhook :exec
|
||||
DELETE
|
||||
FROM webhooks
|
||||
WHERE id = @id;
|
||||
|
||||
------------------------------------------------------------------
|
||||
|
||||
-- name: InsertGroup :one
|
||||
INSERT INTO groups (id, name, permissions, created, updated)
|
||||
VALUES (@id, @name, @permissions, @created, @updated)
|
||||
RETURNING *;
|
||||
|
||||
-- name: CreateGroup :one
|
||||
INSERT INTO groups (name, permissions)
|
||||
VALUES (@name, @permissions)
|
||||
RETURNING *;
|
||||
|
||||
-- name: UpdateGroup :one
|
||||
UPDATE groups
|
||||
SET name = coalesce(sqlc.narg('name'), name),
|
||||
permissions = coalesce(sqlc.narg('permissions'), permissions)
|
||||
WHERE id = @id
|
||||
RETURNING *;
|
||||
|
||||
-- name: DeleteGroup :exec
|
||||
DELETE
|
||||
FROM groups
|
||||
WHERE id = @id;
|
||||
|
||||
-- name: AssignGroupToUser :exec
|
||||
INSERT INTO user_groups (user_id, group_id)
|
||||
VALUES (@user_id, @group_id);
|
||||
|
||||
-- name: RemoveGroupFromUser :exec
|
||||
DELETE
|
||||
FROM user_groups
|
||||
WHERE user_id = @user_id
|
||||
AND group_id = @group_id;
|
||||
|
||||
-- name: AssignParentGroup :exec
|
||||
INSERT INTO group_inheritance (parent_group_id, child_group_id)
|
||||
VALUES (@parent_group_id, @child_group_id);
|
||||
|
||||
-- name: RemoveParentGroup :exec
|
||||
DELETE
|
||||
FROM group_inheritance
|
||||
WHERE parent_group_id = @parent_group_id
|
||||
AND child_group_id = @child_group_id;
|
||||
Reference in New Issue
Block a user