Files
skybridge/user/migrations/001_initial_schema.up.sql
2025-08-31 22:35:23 -04:00

92 lines
3.7 KiB
SQL
Executable File

-- Create users table
CREATE TABLE IF NOT EXISTS users (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
email VARCHAR(255) NOT NULL UNIQUE,
first_name VARCHAR(100) NOT NULL,
last_name VARCHAR(100) NOT NULL,
display_name VARCHAR(200),
avatar VARCHAR(500),
role VARCHAR(50) NOT NULL DEFAULT 'user',
status VARCHAR(50) NOT NULL DEFAULT 'pending',
last_login_at TIMESTAMP WITH TIME ZONE,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
created_by VARCHAR(255) NOT NULL,
updated_by VARCHAR(255) NOT NULL
);
-- Create user_profiles table
CREATE TABLE IF NOT EXISTS user_profiles (
user_id UUID PRIMARY KEY REFERENCES users(id) ON DELETE CASCADE,
bio TEXT,
location VARCHAR(200),
website VARCHAR(500),
timezone VARCHAR(50) DEFAULT 'UTC',
language VARCHAR(10) DEFAULT 'en',
preferences JSONB DEFAULT '{}',
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
);
-- Create user_sessions table
CREATE TABLE IF NOT EXISTS user_sessions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
token VARCHAR(1000) NOT NULL UNIQUE,
ip_address VARCHAR(45) NOT NULL,
user_agent TEXT NOT NULL,
expires_at TIMESTAMP WITH TIME ZONE NOT NULL,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
last_used_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
);
-- Create audit_events table (similar to KMS)
CREATE TABLE IF NOT EXISTS audit_events (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
type VARCHAR(100) NOT NULL,
severity VARCHAR(20) NOT NULL DEFAULT 'info',
status VARCHAR(20) NOT NULL DEFAULT 'success',
timestamp TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
actor_id VARCHAR(255) NOT NULL,
actor_type VARCHAR(50) NOT NULL DEFAULT 'user',
actor_ip VARCHAR(45),
user_agent TEXT,
resource_id VARCHAR(255),
resource_type VARCHAR(100),
action VARCHAR(100) NOT NULL,
description TEXT NOT NULL,
details JSONB DEFAULT '{}',
request_id VARCHAR(255),
session_id VARCHAR(255),
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
);
-- Create indexes for better performance
CREATE INDEX IF NOT EXISTS idx_users_email ON users(email);
CREATE INDEX IF NOT EXISTS idx_users_status ON users(status);
CREATE INDEX IF NOT EXISTS idx_users_role ON users(role);
CREATE INDEX IF NOT EXISTS idx_users_created_at ON users(created_at);
CREATE INDEX IF NOT EXISTS idx_users_updated_at ON users(updated_at);
CREATE INDEX IF NOT EXISTS idx_user_sessions_user_id ON user_sessions(user_id);
CREATE INDEX IF NOT EXISTS idx_user_sessions_token ON user_sessions(token);
CREATE INDEX IF NOT EXISTS idx_user_sessions_expires_at ON user_sessions(expires_at);
CREATE INDEX IF NOT EXISTS idx_audit_events_type ON audit_events(type);
CREATE INDEX IF NOT EXISTS idx_audit_events_actor_id ON audit_events(actor_id);
CREATE INDEX IF NOT EXISTS idx_audit_events_resource_type ON audit_events(resource_type);
CREATE INDEX IF NOT EXISTS idx_audit_events_timestamp ON audit_events(timestamp);
-- Add constraints
ALTER TABLE users ADD CONSTRAINT chk_users_role
CHECK (role IN ('admin', 'user', 'moderator', 'viewer'));
ALTER TABLE users ADD CONSTRAINT chk_users_status
CHECK (status IN ('active', 'inactive', 'suspended', 'pending'));
-- Create initial admin user (optional)
INSERT INTO users (
email, first_name, last_name, role, status, created_by, updated_by
) VALUES (
'admin@example.com', 'System', 'Admin', 'admin', 'active', 'system', 'system'
) ON CONFLICT (email) DO NOTHING;