chore: add init script

This commit is contained in:
Oleg Proskurin 2025-09-27 00:33:46 +07:00
parent f938c63cf6
commit ba85b076ad
1 changed files with 103 additions and 0 deletions

103
scripts/init-db.sql Normal file
View File

@ -0,0 +1,103 @@
-- Banatie Database Initialization Script
-- This script creates the database schema for the Banatie image generation service
-- Enable UUID extension for generating UUIDs
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
-- Organizations table - for multi-tenant support
CREATE TABLE organizations (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name VARCHAR(255) NOT NULL,
slug VARCHAR(100) UNIQUE NOT NULL,
settings JSONB DEFAULT '{}',
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- Users table - users within organizations
CREATE TABLE 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)
);
-- Images table - metadata for generated and uploaded images
CREATE TABLE images (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
user_id UUID REFERENCES users(id) ON DELETE CASCADE,
filename VARCHAR(255) NOT NULL,
file_path VARCHAR(500), -- Legacy: local file path (for backward compatibility)
minio_key VARCHAR(500), -- MinIO object key
url VARCHAR(1000), -- Public or presigned URL to access the image
original_prompt TEXT,
enhanced_prompt TEXT,
model_used VARCHAR(100),
file_size BIGINT,
content_type VARCHAR(100),
category VARCHAR(50) DEFAULT 'generated', -- 'generated', 'references', 'temp'
metadata JSONB DEFAULT '{}',
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- Sessions table - for tracking user upload sessions
CREATE TABLE upload_sessions (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
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 query performance
CREATE INDEX idx_users_org_id ON users(organization_id);
CREATE INDEX idx_users_username ON users(username);
CREATE INDEX idx_images_user_id ON images(user_id);
CREATE INDEX idx_images_created_at ON images(created_at);
CREATE INDEX idx_images_category ON images(category);
CREATE INDEX idx_images_minio_key ON images(minio_key);
CREATE INDEX idx_upload_sessions_user_id ON upload_sessions(user_id);
CREATE INDEX idx_upload_sessions_expires_at ON upload_sessions(expires_at);
-- Insert demo organization and user for development/testing
INSERT INTO organizations (id, name, slug, settings) VALUES
('00000000-0000-0000-0000-000000000001', 'Demo Organization', 'demo', '{"description": "Default demo organization for testing"}');
INSERT INTO users (id, organization_id, username, email, role, settings) VALUES
('00000000-0000-0000-0000-000000000001', '00000000-0000-0000-0000-000000000001', 'guest', 'guest@demo.banatie.app', 'user', '{"description": "Default guest user for testing"}');
-- Create a 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 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_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();
-- Display initialization completion message
DO $$
BEGIN
RAISE NOTICE 'Banatie database initialization completed successfully!';
RAISE NOTICE 'Created tables: organizations, users, images, upload_sessions';
RAISE NOTICE 'Created demo organization (id: 00000000-0000-0000-0000-000000000001) with guest user';
END $$;