Files
file-transformer-s3/database/init.sql

174 lines
6.9 KiB
PL/PgSQL

-- File Transformer S3 Database Schema
-- This script initializes the database with all necessary tables
-- Create extensions
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
CREATE EXTENSION IF NOT EXISTS "pgcrypto";
-- Create tables
CREATE TABLE IF NOT EXISTS files (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
filename VARCHAR(255) NOT NULL,
original_filename VARCHAR(255) NOT NULL,
file_path VARCHAR(500) NOT NULL,
file_size BIGINT NOT NULL,
file_type VARCHAR(50) NOT NULL,
mime_type VARCHAR(100),
bucket_name VARCHAR(100) NOT NULL,
object_key VARCHAR(500) NOT NULL,
checksum VARCHAR(64),
status VARCHAR(20) DEFAULT 'uploaded' CHECK (status IN ('uploaded', 'processing', 'transformed', 'error', 'deleted')),
transformation_type VARCHAR(50),
transformation_config JSONB,
metadata JSONB,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
processed_at TIMESTAMP WITH TIME ZONE,
deleted_at TIMESTAMP WITH TIME ZONE
);
CREATE TABLE IF NOT EXISTS transformations (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
file_id UUID NOT NULL REFERENCES files(id) ON DELETE CASCADE,
transformation_type VARCHAR(50) NOT NULL,
input_path VARCHAR(500) NOT NULL,
output_path VARCHAR(500),
status VARCHAR(20) DEFAULT 'pending' CHECK (status IN ('pending', 'processing', 'completed', 'failed')),
config JSONB,
result JSONB,
error_message TEXT,
started_at TIMESTAMP WITH TIME ZONE,
completed_at TIMESTAMP WITH TIME ZONE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
CREATE TABLE IF NOT EXISTS buckets (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name VARCHAR(100) UNIQUE NOT NULL,
description TEXT,
is_active BOOLEAN DEFAULT true,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
CREATE TABLE IF NOT EXISTS users (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
username VARCHAR(50) UNIQUE NOT NULL,
email VARCHAR(255) UNIQUE NOT NULL,
password_hash VARCHAR(255) NOT NULL,
is_active BOOLEAN DEFAULT true,
role VARCHAR(20) DEFAULT 'user' CHECK (role IN ('admin', 'user')),
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
CREATE TABLE IF NOT EXISTS sessions (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
token VARCHAR(255) UNIQUE NOT NULL,
expires_at TIMESTAMP WITH TIME ZONE NOT NULL,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
CREATE TABLE IF NOT EXISTS file_access_logs (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
file_id UUID REFERENCES files(id) ON DELETE SET NULL,
user_id UUID REFERENCES users(id) ON DELETE SET NULL,
action VARCHAR(50) NOT NULL CHECK (action IN ('upload', 'download', 'view', 'delete', 'transform')),
ip_address INET,
user_agent TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- Create indexes for better performance
CREATE INDEX IF NOT EXISTS idx_files_status ON files(status);
CREATE INDEX IF NOT EXISTS idx_files_file_type ON files(file_type);
CREATE INDEX IF NOT EXISTS idx_files_created_at ON files(created_at);
CREATE INDEX IF NOT EXISTS idx_files_bucket_name ON files(bucket_name);
CREATE INDEX IF NOT EXISTS idx_files_object_key ON files(object_key);
CREATE INDEX IF NOT EXISTS idx_transformations_file_id ON transformations(file_id);
CREATE INDEX IF NOT EXISTS idx_transformations_status ON transformations(status);
CREATE INDEX IF NOT EXISTS idx_transformations_type ON transformations(transformation_type);
CREATE INDEX IF NOT EXISTS idx_sessions_user_id ON sessions(user_id);
CREATE INDEX IF NOT EXISTS idx_sessions_token ON sessions(token);
CREATE INDEX IF NOT EXISTS idx_sessions_expires_at ON sessions(expires_at);
CREATE INDEX IF NOT EXISTS idx_file_access_logs_file_id ON file_access_logs(file_id);
CREATE INDEX IF NOT EXISTS idx_file_access_logs_user_id ON file_access_logs(user_id);
CREATE INDEX IF NOT EXISTS idx_file_access_logs_action ON file_access_logs(action);
CREATE INDEX IF NOT EXISTS idx_file_access_logs_created_at ON file_access_logs(created_at);
-- Create updated_at trigger function
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = CURRENT_TIMESTAMP;
RETURN NEW;
END;
$$ language 'plpgsql';
-- Create triggers for updated_at
CREATE TRIGGER update_files_updated_at BEFORE UPDATE ON files
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_transformations_updated_at BEFORE UPDATE ON transformations
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_buckets_updated_at BEFORE UPDATE ON buckets
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();
-- Insert default bucket
INSERT INTO buckets (name, description)
VALUES ('file-transformer-bucket', 'Default bucket for file transformations')
ON CONFLICT (name) DO NOTHING;
-- Insert default admin user (password: admin123)
INSERT INTO users (username, email, password_hash, role)
VALUES (
'admin',
'admin@file-transformer.local',
crypt('admin123', gen_salt('bf')),
'admin'
) ON CONFLICT (username) DO NOTHING;
-- Create views for common queries
CREATE OR REPLACE VIEW file_summary AS
SELECT
f.id,
f.filename,
f.original_filename,
f.file_size,
f.file_type,
f.status,
f.transformation_type,
f.created_at,
f.updated_at,
COUNT(t.id) as transformation_count,
COUNT(CASE WHEN t.status = 'completed' THEN 1 END) as completed_transformations,
COUNT(CASE WHEN t.status = 'failed' THEN 1 END) as failed_transformations
FROM files f
LEFT JOIN transformations t ON f.id = t.file_id
GROUP BY f.id, f.filename, f.original_filename, f.file_size, f.file_type, f.status, f.transformation_type, f.created_at, f.updated_at;
CREATE OR REPLACE VIEW bucket_stats AS
SELECT
b.name as bucket_name,
COUNT(f.id) as total_files,
SUM(f.file_size) as total_size,
COUNT(CASE WHEN f.status = 'uploaded' THEN 1 END) as uploaded_files,
COUNT(CASE WHEN f.status = 'processing' THEN 1 END) as processing_files,
COUNT(CASE WHEN f.status = 'transformed' THEN 1 END) as transformed_files,
COUNT(CASE WHEN f.status = 'error' THEN 1 END) as error_files
FROM buckets b
LEFT JOIN files f ON b.name = f.bucket_name
GROUP BY b.name;
-- Grant permissions (adjust as needed for your setup)
-- GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO file_user;
-- GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA public TO file_user;