refactor: remove pocketbase (#1138)

This commit is contained in:
Jonas Plum
2025-09-02 21:58:08 +02:00
committed by GitHub
parent f28c238135
commit eba2615ec0
435 changed files with 42677 additions and 4730 deletions

View 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;

View 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;

View 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);

View 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;

View File

@@ -0,0 +1,6 @@
package migrations
import "embed"
//go:embed *.sql
var Migrations embed.FS