118 lines
4.6 KiB
PL/PgSQL
118 lines
4.6 KiB
PL/PgSQL
-- Migration: 001_initial_schema.sql
|
|
-- Create initial schema for multi-tenant geek-life application
|
|
|
|
-- Enable UUID extension
|
|
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
|
|
|
-- Create tenants table
|
|
CREATE TABLE IF NOT EXISTS tenants (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
name VARCHAR(255) NOT NULL UNIQUE,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Create users table
|
|
CREATE TABLE IF NOT EXISTS users (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
tenant_id BIGINT NOT NULL REFERENCES tenants(id) ON DELETE CASCADE,
|
|
username VARCHAR(100) NOT NULL,
|
|
email VARCHAR(255) NOT NULL,
|
|
password_hash VARCHAR(255) NOT NULL,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
UNIQUE(tenant_id, username),
|
|
UNIQUE(tenant_id, email)
|
|
);
|
|
|
|
-- Create projects table
|
|
CREATE TABLE IF NOT EXISTS projects (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
tenant_id BIGINT NOT NULL REFERENCES tenants(id) ON DELETE CASCADE,
|
|
user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
title VARCHAR(255) NOT NULL,
|
|
uuid UUID NOT NULL DEFAULT uuid_generate_v4() UNIQUE,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Create tasks table
|
|
CREATE TABLE IF NOT EXISTS tasks (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
tenant_id BIGINT NOT NULL REFERENCES tenants(id) ON DELETE CASCADE,
|
|
user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
project_id BIGINT NOT NULL REFERENCES projects(id) ON DELETE CASCADE,
|
|
uuid UUID NOT NULL DEFAULT uuid_generate_v4() UNIQUE,
|
|
title VARCHAR(500) NOT NULL,
|
|
details TEXT,
|
|
completed BOOLEAN NOT NULL DEFAULT FALSE,
|
|
due_date TIMESTAMP,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Create user_sessions table
|
|
CREATE TABLE IF NOT EXISTS user_sessions (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
token VARCHAR(255) NOT NULL UNIQUE,
|
|
expires_at TIMESTAMP NOT NULL,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Create indexes for better performance
|
|
CREATE INDEX IF NOT EXISTS idx_users_tenant_id ON users(tenant_id);
|
|
CREATE INDEX IF NOT EXISTS idx_projects_tenant_user ON projects(tenant_id, user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_projects_uuid ON projects(uuid);
|
|
CREATE INDEX IF NOT EXISTS idx_tasks_tenant_user ON tasks(tenant_id, user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_tasks_project_id ON tasks(project_id);
|
|
CREATE INDEX IF NOT EXISTS idx_tasks_completed ON tasks(completed);
|
|
CREATE INDEX IF NOT EXISTS idx_tasks_due_date ON tasks(due_date);
|
|
CREATE INDEX IF NOT EXISTS idx_tasks_uuid ON tasks(uuid);
|
|
CREATE INDEX IF NOT EXISTS idx_sessions_token ON user_sessions(token);
|
|
CREATE INDEX IF NOT EXISTS idx_sessions_expires_at ON user_sessions(expires_at);
|
|
|
|
-- Enable Row Level Security
|
|
ALTER TABLE tenants ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE users ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE projects ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE tasks ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE user_sessions ENABLE ROW LEVEL SECURITY;
|
|
|
|
-- Create RLS policies (these will be managed by the application)
|
|
-- Users can only see their own tenant's data
|
|
CREATE POLICY tenant_isolation_users ON users
|
|
USING (tenant_id = current_setting('app.current_tenant_id')::bigint);
|
|
|
|
CREATE POLICY tenant_isolation_projects ON projects
|
|
USING (tenant_id = current_setting('app.current_tenant_id')::bigint AND
|
|
user_id = current_setting('app.current_user_id')::bigint);
|
|
|
|
CREATE POLICY tenant_isolation_tasks ON tasks
|
|
USING (tenant_id = current_setting('app.current_tenant_id')::bigint AND
|
|
user_id = current_setting('app.current_user_id')::bigint);
|
|
|
|
CREATE POLICY tenant_isolation_sessions ON user_sessions
|
|
USING (user_id = current_setting('app.current_user_id')::bigint);
|
|
|
|
-- Create function to update updated_at timestamp
|
|
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.updated_at = NOW();
|
|
RETURN NEW;
|
|
END;
|
|
$$ language 'plpgsql';
|
|
|
|
-- Create triggers for updated_at
|
|
CREATE TRIGGER update_tenants_updated_at BEFORE UPDATE ON tenants
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
CREATE TRIGGER update_projects_updated_at BEFORE UPDATE ON projects
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
CREATE TRIGGER update_tasks_updated_at BEFORE UPDATE ON tasks
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); |