
Some checks failed
CI/CD Pipeline / Test Suite (push) Has been cancelled
CI/CD Pipeline / Security Audit (push) Has been cancelled
CI/CD Pipeline / Build Docker Image (push) Has been cancelled
CI/CD Pipeline / Deploy to Staging (push) Has been cancelled
CI/CD Pipeline / Deploy to Production (push) Has been cancelled
CI/CD Pipeline / Performance Benchmarks (push) Has been cancelled
CI/CD Pipeline / Cleanup (push) Has been cancelled
97 lines
3.8 KiB
SQL
97 lines
3.8 KiB
SQL
-- Initial database setup for SQLite
|
|
-- Migration: 001_initial_setup
|
|
-- Database: SQLite
|
|
|
|
-- Users table for authentication
|
|
CREATE TABLE IF NOT EXISTS users (
|
|
id TEXT PRIMARY KEY DEFAULT (lower(hex(randomblob(16)))),
|
|
username TEXT NOT NULL UNIQUE,
|
|
email TEXT NOT NULL UNIQUE,
|
|
password_hash TEXT NOT NULL,
|
|
is_active INTEGER NOT NULL DEFAULT 1,
|
|
is_verified INTEGER NOT NULL DEFAULT 0,
|
|
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- User sessions table
|
|
CREATE TABLE IF NOT EXISTS user_sessions (
|
|
id TEXT PRIMARY KEY DEFAULT (lower(hex(randomblob(16)))),
|
|
user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
session_token TEXT NOT NULL UNIQUE,
|
|
expires_at DATETIME NOT NULL,
|
|
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Content table for CMS functionality
|
|
CREATE TABLE IF NOT EXISTS content (
|
|
id TEXT PRIMARY KEY DEFAULT (lower(hex(randomblob(16)))),
|
|
title TEXT NOT NULL,
|
|
slug TEXT NOT NULL UNIQUE,
|
|
content_type TEXT NOT NULL DEFAULT 'markdown',
|
|
body TEXT,
|
|
metadata TEXT, -- JSON as TEXT in SQLite
|
|
is_published INTEGER NOT NULL DEFAULT 0,
|
|
published_at DATETIME,
|
|
created_by TEXT REFERENCES users(id),
|
|
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- User roles table
|
|
CREATE TABLE IF NOT EXISTS user_roles (
|
|
id TEXT PRIMARY KEY DEFAULT (lower(hex(randomblob(16)))),
|
|
name TEXT NOT NULL UNIQUE,
|
|
description TEXT,
|
|
permissions TEXT, -- JSON as TEXT in SQLite
|
|
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- User role assignments
|
|
CREATE TABLE IF NOT EXISTS user_role_assignments (
|
|
id TEXT PRIMARY KEY DEFAULT (lower(hex(randomblob(16)))),
|
|
user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
role_id TEXT NOT NULL REFERENCES user_roles(id) ON DELETE CASCADE,
|
|
assigned_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
assigned_by TEXT REFERENCES users(id),
|
|
UNIQUE(user_id, role_id)
|
|
);
|
|
|
|
-- Create indexes for better performance
|
|
CREATE INDEX IF NOT EXISTS idx_users_email ON users(email);
|
|
CREATE INDEX IF NOT EXISTS idx_users_username ON users(username);
|
|
CREATE INDEX IF NOT EXISTS idx_users_active ON users(is_active);
|
|
CREATE INDEX IF NOT EXISTS idx_user_sessions_token ON user_sessions(session_token);
|
|
CREATE INDEX IF NOT EXISTS idx_user_sessions_user_id ON user_sessions(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_user_sessions_expires ON user_sessions(expires_at);
|
|
CREATE INDEX IF NOT EXISTS idx_content_slug ON content(slug);
|
|
CREATE INDEX IF NOT EXISTS idx_content_published ON content(is_published);
|
|
CREATE INDEX IF NOT EXISTS idx_content_created_by ON content(created_by);
|
|
CREATE INDEX IF NOT EXISTS idx_content_type ON content(content_type);
|
|
CREATE INDEX IF NOT EXISTS idx_user_role_assignments_user ON user_role_assignments(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_user_role_assignments_role ON user_role_assignments(role_id);
|
|
|
|
-- Triggers for updated_at timestamps (SQLite doesn't have automatic timestamp updates)
|
|
CREATE TRIGGER IF NOT EXISTS update_users_updated_at
|
|
AFTER UPDATE ON users
|
|
FOR EACH ROW
|
|
WHEN NEW.updated_at = OLD.updated_at
|
|
BEGIN
|
|
UPDATE users SET updated_at = CURRENT_TIMESTAMP WHERE id = NEW.id;
|
|
END;
|
|
|
|
CREATE TRIGGER IF NOT EXISTS update_content_updated_at
|
|
AFTER UPDATE ON content
|
|
FOR EACH ROW
|
|
WHEN NEW.updated_at = OLD.updated_at
|
|
BEGIN
|
|
UPDATE content SET updated_at = CURRENT_TIMESTAMP WHERE id = NEW.id;
|
|
END;
|
|
|
|
-- Insert default roles
|
|
INSERT INTO user_roles (name, description, permissions) VALUES
|
|
('admin', 'Administrator with full access', '{"all": true}'),
|
|
('editor', 'Content editor', '{"content": {"read": true, "write": true, "delete": true}}'),
|
|
('user', 'Regular user', '{"content": {"read": true}}')
|
|
ON CONFLICT (name) DO NOTHING;
|