-- Enable UUID extension for UUIDv7 support CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- UUIDv7 generation function (timestamp-ordered UUIDs) -- Based on the draft RFC: https://datatracker.ietf.org/doc/html/draft-peabody-dispatch-new-uuid-format CREATE OR REPLACE FUNCTION uuid_generate_v7() RETURNS UUID AS $$ DECLARE unix_ts_ms BIGINT; uuid_bytes BYTEA; BEGIN unix_ts_ms = (EXTRACT(EPOCH FROM CLOCK_TIMESTAMP()) * 1000)::BIGINT; uuid_bytes = OVERLAY(gen_random_bytes(16) PLACING SUBSTRING(INT8SEND(unix_ts_ms) FROM 3) FROM 1 FOR 6 ); -- Set version (7) and variant bits uuid_bytes = SET_BYTE(uuid_bytes, 6, (GET_BYTE(uuid_bytes, 6) & 15) | 112); uuid_bytes = SET_BYTE(uuid_bytes, 8, (GET_BYTE(uuid_bytes, 8) & 63) | 128); RETURN ENCODE(uuid_bytes, 'hex')::UUID; END; $$ LANGUAGE plpgsql VOLATILE; -- ============================================================================ -- Application Tables -- ============================================================================ CREATE TABLE IF NOT EXISTS users ( id UUID PRIMARY KEY DEFAULT uuid_generate_v7(), display_name TEXT, email TEXT NOT NULL UNIQUE, password TEXT NOT NULL, storage_usage_bytes BIGINT NOT NULL, storage_quota_bytes BIGINT NOT NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX idx_users_email ON users(email); CREATE TABLE IF NOT EXISTS refresh_tokens ( id UUID PRIMARY KEY DEFAULT uuid_generate_v7(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, token_hash TEXT NOT NULL UNIQUE, expires_at TIMESTAMPTZ NOT NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX idx_refresh_tokens_user_id ON refresh_tokens(user_id); CREATE INDEX idx_refresh_tokens_token_hash ON refresh_tokens(token_hash); CREATE INDEX idx_refresh_tokens_expires_at ON refresh_tokens(expires_at); CREATE TABLE IF NOT EXISTS directories ( id UUID PRIMARY KEY DEFAULT uuid_generate_v7(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, name TEXT NOT NULL, parent_id UUID REFERENCES directories(id) ON DELETE CASCADE, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), deleted_at TIMESTAMPTZ, CONSTRAINT unique_directory_path UNIQUE NULLS NOT DISTINCT (user_id, parent_id, name, deleted_at) ); CREATE INDEX idx_directories_user_id ON directories(user_id, deleted_at); CREATE INDEX idx_directories_path ON directories(user_id, path, deleted_at); CREATE TABLE IF NOT EXISTS files ( id UUID PRIMARY KEY DEFAULT uuid_generate_v7(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, directory_id UUID REFERENCES directories(id) ON DELETE CASCADE, name TEXT NOT NULL, size BIGINT NOT NULL, mime_type TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), deleted_at TIMESTAMPTZ, last_accessed_at TIMESTAMPTZ, CONSTRAINT unique_file_in_directory UNIQUE NULLS NOT DISTINCT (user_id, directory_id, name, deleted_at) ); CREATE INDEX idx_files_user_id ON files(user_id, deleted_at); CREATE INDEX idx_files_directory_id ON files(directory_id) WHERE directory_id IS NOT NULL; CREATE INDEX idx_files_path ON files(user_id, path, deleted_at); CREATE INDEX idx_files_deleted_at ON files(deleted_at) WHERE deleted_at IS NOT NULL; CREATE INDEX idx_files_last_accessed_at ON files(user_id, deleted_at, last_accessed_at); CREATE TABLE IF NOT EXISTS file_shares ( id UUID PRIMARY KEY DEFAULT uuid_generate_v7(), file_id UUID NOT NULL REFERENCES files(id) ON DELETE CASCADE, share_token TEXT NOT NULL UNIQUE, expires_at TIMESTAMPTZ, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX idx_file_shares_share_token ON file_shares(share_token); CREATE INDEX idx_file_shares_file_id ON file_shares(file_id); CREATE INDEX idx_file_shares_expires_at ON file_shares(expires_at) WHERE expires_at IS NOT NULL; -- ============================================================================ -- Triggers for updated_at timestamps -- ============================================================================ CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_directories_updated_at BEFORE UPDATE ON directories FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_files_updated_at BEFORE UPDATE ON files FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_file_shares_updated_at BEFORE UPDATE ON file_shares FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();