banatie-service/scripts/init-db.sql

129 lines
5.9 KiB
PL/PgSQL

-- Banatie Database Initialization Script
-- This script creates the initial database schema for the Banatie image generation service
-- Enable UUID extension
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
-- Organizations table
CREATE TABLE IF NOT EXISTS organizations (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name VARCHAR(255) NOT NULL,
slug VARCHAR(100) UNIQUE NOT NULL,
description TEXT,
settings JSONB DEFAULT '{}',
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- Projects table (within organizations)
CREATE TABLE IF NOT EXISTS projects (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
organization_id UUID REFERENCES organizations(id) ON DELETE CASCADE,
name VARCHAR(255) NOT NULL,
slug VARCHAR(100) NOT NULL,
description TEXT,
settings JSONB DEFAULT '{}',
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
UNIQUE(organization_id, slug)
);
-- Users table
CREATE TABLE IF NOT EXISTS users (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
organization_id UUID REFERENCES organizations(id) ON DELETE CASCADE,
username VARCHAR(100) NOT NULL,
email VARCHAR(255),
role VARCHAR(50) DEFAULT 'user',
settings JSONB DEFAULT '{}',
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
UNIQUE(organization_id, username)
);
-- Image metadata table
CREATE TABLE IF NOT EXISTS images (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
organization_id UUID REFERENCES organizations(id) ON DELETE CASCADE,
project_id UUID REFERENCES projects(id) ON DELETE CASCADE,
user_id UUID REFERENCES users(id) ON DELETE CASCADE,
filename VARCHAR(255) NOT NULL,
original_filename VARCHAR(255),
file_path VARCHAR(500) NOT NULL, -- Path in MinIO
category VARCHAR(50) NOT NULL CHECK (category IN ('uploads', 'generated', 'references')),
original_prompt TEXT,
enhanced_prompt TEXT,
model_used VARCHAR(100),
file_size BIGINT,
content_type VARCHAR(100),
metadata JSONB DEFAULT '{}',
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- Upload sessions table (for tracking multi-part uploads)
CREATE TABLE IF NOT EXISTS upload_sessions (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
organization_id UUID REFERENCES organizations(id) ON DELETE CASCADE,
project_id UUID REFERENCES projects(id) ON DELETE CASCADE,
user_id UUID REFERENCES users(id) ON DELETE CASCADE,
session_data JSONB NOT NULL,
expires_at TIMESTAMP WITH TIME ZONE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- Create indexes for better performance
CREATE INDEX IF NOT EXISTS idx_organizations_slug ON organizations(slug);
CREATE INDEX IF NOT EXISTS idx_projects_org_id ON projects(organization_id);
CREATE INDEX IF NOT EXISTS idx_projects_org_slug ON projects(organization_id, slug);
CREATE INDEX IF NOT EXISTS idx_users_org_id ON users(organization_id);
CREATE INDEX IF NOT EXISTS idx_users_org_username ON users(organization_id, username);
CREATE INDEX IF NOT EXISTS idx_images_org_id ON images(organization_id);
CREATE INDEX IF NOT EXISTS idx_images_project_id ON images(project_id);
CREATE INDEX IF NOT EXISTS idx_images_user_id ON images(user_id);
CREATE INDEX IF NOT EXISTS idx_images_category ON images(category);
CREATE INDEX IF NOT EXISTS idx_images_created_at ON images(created_at);
CREATE INDEX IF NOT EXISTS idx_upload_sessions_user_id ON upload_sessions(user_id);
CREATE INDEX IF NOT EXISTS idx_upload_sessions_expires_at ON upload_sessions(expires_at);
-- Function to update the 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 to automatically update updated_at
CREATE TRIGGER update_organizations_updated_at BEFORE UPDATE ON organizations 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_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_images_updated_at BEFORE UPDATE ON images FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
-- Insert default organization and project
INSERT INTO organizations (id, name, slug, description) VALUES
('00000000-0000-0000-0000-000000000001', 'Default Organization', 'default', 'Default organization for development and testing')
ON CONFLICT (slug) DO NOTHING;
INSERT INTO projects (id, organization_id, name, slug, description) VALUES
('00000000-0000-0000-0000-000000000001', '00000000-0000-0000-0000-000000000001', 'Main Project', 'main', 'Main project for image generation')
ON CONFLICT (organization_id, slug) DO NOTHING;
-- Insert system user
INSERT INTO users (id, organization_id, username, role) VALUES
('00000000-0000-0000-0000-000000000001', '00000000-0000-0000-0000-000000000001', 'system', 'admin')
ON CONFLICT (organization_id, username) DO NOTHING;
-- Insert demo organization for development
INSERT INTO organizations (id, name, slug, description) VALUES
('00000000-0000-0000-0000-000000000002', 'Demo Organization', 'demo', 'Demo organization for testing and development')
ON CONFLICT (slug) DO NOTHING;
INSERT INTO projects (id, organization_id, name, slug, description) VALUES
('00000000-0000-0000-0000-000000000002', '00000000-0000-0000-0000-000000000002', 'Sandbox Project', 'sandbox', 'Sandbox project for testing features')
ON CONFLICT (organization_id, slug) DO NOTHING;
INSERT INTO users (id, organization_id, username, role) VALUES
('00000000-0000-0000-0000-000000000002', '00000000-0000-0000-0000-000000000002', 'guest', 'user')
ON CONFLICT (organization_id, username) DO NOTHING;