Update initial tables
This commit is contained in:
@@ -87,8 +87,8 @@ async function raw<T = unknown>(
|
|||||||
// ============================================================================
|
// ============================================================================
|
||||||
|
|
||||||
// Migration file naming convention:
|
// Migration file naming convention:
|
||||||
// NNNN_description.sql
|
// yyyy-mm-dd_ss_description.sql
|
||||||
// e.g., 0001_initial.sql, 0002_add_users.sql
|
// e.g., 2025-01-15_01_initial.sql, 2025-01-15_02_add_users.sql
|
||||||
//
|
//
|
||||||
// Migrations directory: express/migrations/
|
// Migrations directory: express/migrations/
|
||||||
|
|
||||||
@@ -128,7 +128,7 @@ function getMigrationFiles(): string[] {
|
|||||||
return fs
|
return fs
|
||||||
.readdirSync(MIGRATIONS_DIR)
|
.readdirSync(MIGRATIONS_DIR)
|
||||||
.filter((f) => f.endsWith(".sql"))
|
.filter((f) => f.endsWith(".sql"))
|
||||||
.filter((f) => /^\d{4}_/.test(f))
|
.filter((f) => /^\d{4}-\d{2}-\d{2}_\d{2}-/.test(f))
|
||||||
.sort();
|
.sort();
|
||||||
}
|
}
|
||||||
|
|
||||||
|
|||||||
@@ -1,21 +0,0 @@
|
|||||||
-- 0001_users.sql
|
|
||||||
-- Create users table for authentication
|
|
||||||
|
|
||||||
CREATE TABLE users (
|
|
||||||
id UUID PRIMARY KEY,
|
|
||||||
email TEXT UNIQUE NOT NULL,
|
|
||||||
password_hash TEXT NOT NULL,
|
|
||||||
display_name TEXT,
|
|
||||||
status TEXT NOT NULL DEFAULT 'pending',
|
|
||||||
roles TEXT[] NOT NULL DEFAULT '{}',
|
|
||||||
permissions TEXT[] NOT NULL DEFAULT '{}',
|
|
||||||
email_verified BOOLEAN NOT NULL DEFAULT FALSE,
|
|
||||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
||||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
|
||||||
);
|
|
||||||
|
|
||||||
-- Index for email lookups (login)
|
|
||||||
CREATE INDEX users_email_idx ON users (LOWER(email));
|
|
||||||
|
|
||||||
-- Index for status filtering
|
|
||||||
CREATE INDEX users_status_idx ON users (status);
|
|
||||||
29
express/migrations/2026-01-01_01-users.sql
Normal file
29
express/migrations/2026-01-01_01-users.sql
Normal file
@@ -0,0 +1,29 @@
|
|||||||
|
-- 0001_users.sql
|
||||||
|
-- Create users table for authentication
|
||||||
|
|
||||||
|
CREATE TABLE users (
|
||||||
|
id UUID PRIMARY KEY,
|
||||||
|
status TEXT NOT NULL DEFAULT 'active',
|
||||||
|
display_name TEXT,
|
||||||
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||||
|
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE TABLE user_emails (
|
||||||
|
id UUID PRIMARY KEY,
|
||||||
|
user_id UUID NOT NULL REFERENCES users(id),
|
||||||
|
email TEXT NOT NULL,
|
||||||
|
normalized_email TEXT NOT NULL,
|
||||||
|
is_primary BOOLEAN NOT NULL DEFAULT FALSE,
|
||||||
|
is_verified BOOLEAN NOT NULL DEFAULT FALSE,
|
||||||
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||||
|
verified_at TIMESTAMPTZ,
|
||||||
|
revoked_at TIMESTAMPTZ
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Enforce uniqueness only among *active* emails
|
||||||
|
CREATE UNIQUE INDEX user_emails_unique_active
|
||||||
|
ON user_emails (normalized_email)
|
||||||
|
WHERE revoked_at IS NULL;
|
||||||
|
|
||||||
|
|
||||||
@@ -2,15 +2,16 @@
|
|||||||
-- Create sessions table for auth tokens
|
-- Create sessions table for auth tokens
|
||||||
|
|
||||||
CREATE TABLE sessions (
|
CREATE TABLE sessions (
|
||||||
token_id TEXT PRIMARY KEY,
|
id UUID PRIMARY KEY,
|
||||||
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
user_id UUID NOT NULL REFERENCES users(id),
|
||||||
|
user_email_id UUID REFERENCES user_emails(id),
|
||||||
token_type TEXT NOT NULL,
|
token_type TEXT NOT NULL,
|
||||||
auth_method TEXT NOT NULL,
|
auth_method TEXT NOT NULL,
|
||||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||||
expires_at TIMESTAMPTZ NOT NULL,
|
expires_at TIMESTAMPTZ NOT NULL,
|
||||||
last_used_at TIMESTAMPTZ,
|
revoked_at TIMESTAMPTZ,
|
||||||
|
ip_address INET,
|
||||||
user_agent TEXT,
|
user_agent TEXT,
|
||||||
ip_address TEXT,
|
|
||||||
is_used BOOLEAN DEFAULT FALSE
|
is_used BOOLEAN DEFAULT FALSE
|
||||||
);
|
);
|
||||||
|
|
||||||
20
express/migrations/2026-01-24_01-roles-and-groups.sql
Normal file
20
express/migrations/2026-01-24_01-roles-and-groups.sql
Normal file
@@ -0,0 +1,20 @@
|
|||||||
|
CREATE TABLE roles (
|
||||||
|
id UUID PRIMARY KEY,
|
||||||
|
name TEXT UNIQUE NOT NULL,
|
||||||
|
description TEXT
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE TABLE groups (
|
||||||
|
id UUID PRIMARY KEY,
|
||||||
|
name TEXT NOT NULL,
|
||||||
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE TABLE user_group_roles (
|
||||||
|
user_id UUID NOT NULL REFERENCES users(id),
|
||||||
|
group_id UUID NOT NULL REFERENCES groups(id),
|
||||||
|
role_id UUID NOT NULL REFERENCES roles(id),
|
||||||
|
granted_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||||
|
revoked_at TIMESTAMPTZ,
|
||||||
|
PRIMARY KEY (user_id, group_id, role_id)
|
||||||
|
);
|
||||||
14
express/migrations/2026-01-24_02-capabilities.sql
Normal file
14
express/migrations/2026-01-24_02-capabilities.sql
Normal file
@@ -0,0 +1,14 @@
|
|||||||
|
CREATE TABLE capabilities (
|
||||||
|
id UUID PRIMARY KEY,
|
||||||
|
name TEXT UNIQUE NOT NULL,
|
||||||
|
description TEXT
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE TABLE role_capabilities (
|
||||||
|
role_id UUID NOT NULL REFERENCES roles(id),
|
||||||
|
capability_id UUID NOT NULL REFERENCES capabilities(id),
|
||||||
|
granted_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||||
|
revoked_at TIMESTAMPTZ,
|
||||||
|
PRIMARY KEY (role_id, capability_id)
|
||||||
|
);
|
||||||
|
|
||||||
Reference in New Issue
Block a user