110 lines
No EOL
4 KiB
PL/PgSQL
110 lines
No EOL
4 KiB
PL/PgSQL
-- Create users table
|
|
CREATE TABLE IF NOT EXISTS users (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
username VARCHAR(255) UNIQUE NOT NULL,
|
|
password_hash VARCHAR(255),
|
|
is_admin BOOLEAN DEFAULT false,
|
|
is_streamer BOOLEAN DEFAULT false,
|
|
is_pgp_only BOOLEAN DEFAULT false,
|
|
pgp_only_enabled_at TIMESTAMP WITH TIME ZONE,
|
|
bio TEXT DEFAULT '',
|
|
avatar_url VARCHAR(255),
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Create pgp_keys table
|
|
CREATE TABLE IF NOT EXISTS pgp_keys (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
public_key TEXT NOT NULL,
|
|
fingerprint VARCHAR(40) UNIQUE NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Create realms table (removed display_name and description)
|
|
CREATE TABLE IF NOT EXISTS realms (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
name VARCHAR(255) UNIQUE NOT NULL,
|
|
stream_key VARCHAR(64) UNIQUE NOT NULL,
|
|
is_active BOOLEAN DEFAULT true,
|
|
is_live BOOLEAN DEFAULT false,
|
|
viewer_count INTEGER DEFAULT 0,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Create stream_keys table (deprecated, kept for compatibility)
|
|
CREATE TABLE IF NOT EXISTS stream_keys (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
key VARCHAR(64) UNIQUE NOT NULL,
|
|
is_active BOOLEAN DEFAULT true,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Create indexes
|
|
CREATE INDEX idx_users_username ON users(username);
|
|
CREATE INDEX idx_users_is_streamer ON users(is_streamer);
|
|
CREATE INDEX idx_users_is_pgp_only ON users(is_pgp_only);
|
|
CREATE INDEX idx_pgp_keys_user_id ON pgp_keys(user_id);
|
|
CREATE INDEX idx_pgp_keys_fingerprint ON pgp_keys(fingerprint);
|
|
CREATE INDEX idx_realms_user_id ON realms(user_id);
|
|
CREATE INDEX idx_realms_name ON realms(name);
|
|
CREATE INDEX idx_realms_stream_key ON realms(stream_key);
|
|
CREATE INDEX idx_realms_is_live ON realms(is_live);
|
|
CREATE INDEX idx_stream_keys_user_id ON stream_keys(user_id);
|
|
CREATE INDEX idx_stream_keys_key ON stream_keys(key) WHERE is_active = true;
|
|
CREATE INDEX idx_stream_keys_active ON stream_keys(is_active);
|
|
|
|
-- Create updated_at trigger
|
|
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.updated_at = CURRENT_TIMESTAMP;
|
|
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_realms_updated_at BEFORE UPDATE ON realms
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
CREATE TRIGGER update_stream_keys_updated_at BEFORE UPDATE ON stream_keys
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
-- Create function to deactivate old keys when a new one is created
|
|
CREATE OR REPLACE FUNCTION deactivate_old_stream_keys()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
IF NEW.is_active = true THEN
|
|
UPDATE stream_keys
|
|
SET is_active = false
|
|
WHERE user_id = NEW.user_id
|
|
AND id != NEW.id
|
|
AND is_active = true;
|
|
END IF;
|
|
RETURN NEW;
|
|
END;
|
|
$$ language 'plpgsql';
|
|
|
|
CREATE TRIGGER deactivate_old_keys AFTER INSERT OR UPDATE ON stream_keys
|
|
FOR EACH ROW EXECUTE FUNCTION deactivate_old_stream_keys();
|
|
|
|
-- Add constraint to ensure pgp_only_enabled_at is set when is_pgp_only is true
|
|
CREATE OR REPLACE FUNCTION check_pgp_only_timestamp()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
IF NEW.is_pgp_only = true AND NEW.pgp_only_enabled_at IS NULL THEN
|
|
NEW.pgp_only_enabled_at = CURRENT_TIMESTAMP;
|
|
END IF;
|
|
RETURN NEW;
|
|
END;
|
|
$$ language 'plpgsql';
|
|
|
|
CREATE TRIGGER ensure_pgp_only_timestamp BEFORE INSERT OR UPDATE ON users
|
|
FOR EACH ROW EXECUTE FUNCTION check_pgp_only_timestamp(); |