feat: add ddl

This commit is contained in:
itqop 2025-10-15 23:35:20 +03:00
parent 736e12cd08
commit eb96c98878
6 changed files with 262 additions and 5 deletions

257
db.ddl Normal file
View File

@ -0,0 +1,257 @@
-- ============================================================
-- LUCKPERMS TABLES
-- ============================================================
-- Таблица игроков LuckPerms
CREATE TABLE IF NOT EXISTS luckperms_players (
uuid VARCHAR(36) PRIMARY KEY,
username VARCHAR(16) NOT NULL,
primary_group VARCHAR(36) NOT NULL,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- Индексы для luckperms_players
CREATE INDEX IF NOT EXISTS idx_luckperms_players_username ON luckperms_players(username);
-- Таблица групп LuckPerms
CREATE TABLE IF NOT EXISTS luckperms_groups (
name VARCHAR(36) PRIMARY KEY,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- Таблица прав пользователей LuckPerms
CREATE TABLE IF NOT EXISTS luckperms_user_permissions (
id SERIAL PRIMARY KEY,
uuid VARCHAR(36) NOT NULL,
permission VARCHAR(200) NOT NULL,
value BOOLEAN NOT NULL,
server VARCHAR(36),
world VARCHAR(64),
expiry BIGINT,
contexts VARCHAR(200),
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
FOREIGN KEY (uuid) REFERENCES luckperms_players(uuid) ON DELETE CASCADE
);
-- Индексы для luckperms_user_permissions
CREATE INDEX IF NOT EXISTS idx_luckperms_user_permissions_uuid ON luckperms_user_permissions(uuid);
CREATE INDEX IF NOT EXISTS idx_luckperms_user_permissions_lookup ON luckperms_user_permissions(uuid, permission, server, world);
-- ============================================================
-- HUB TABLES
-- ============================================================
-- Таблица кулдаунов (ИСПРАВЛЕНО)
CREATE TABLE IF NOT EXISTS hub_cooldowns (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
player_uuid VARCHAR(36) NOT NULL,
cooldown_type VARCHAR(50) NOT NULL,
expires_at TIMESTAMP WITH TIME ZONE NOT NULL,
cooldown_seconds INTEGER NOT NULL,
metadata JSONB,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
FOREIGN KEY (player_uuid) REFERENCES luckperms_players(uuid) ON DELETE CASCADE
);
-- Индексы для hub_cooldowns
CREATE UNIQUE INDEX IF NOT EXISTS idx_hub_cooldowns_player_type ON hub_cooldowns(player_uuid, cooldown_type);
CREATE INDEX IF NOT EXISTS idx_hub_cooldowns_expires ON hub_cooldowns(expires_at);
CREATE INDEX IF NOT EXISTS idx_hub_cooldowns_player_uuid ON hub_cooldowns(player_uuid);
-- Таблица домов игроков
CREATE TABLE IF NOT EXISTS hub_homes (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
player_uuid VARCHAR(36) NOT NULL,
name VARCHAR(255) NOT NULL,
world TEXT NOT NULL,
x DOUBLE PRECISION NOT NULL,
y DOUBLE PRECISION NOT NULL,
z DOUBLE PRECISION NOT NULL,
yaw REAL DEFAULT 0.0,
pitch REAL DEFAULT 0.0,
is_public BOOLEAN DEFAULT false,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
FOREIGN KEY (player_uuid) REFERENCES luckperms_players(uuid) ON DELETE CASCADE
);
-- Индексы для hub_homes
CREATE INDEX IF NOT EXISTS idx_hub_homes_player_uuid ON hub_homes(player_uuid);
CREATE UNIQUE INDEX IF NOT EXISTS idx_hub_homes_player_name ON hub_homes(player_uuid, name);
-- Таблица наказаний (ДОПОЛНЕНО)
CREATE TABLE IF NOT EXISTS hub_punishments (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
player_uuid VARCHAR(36) NOT NULL,
player_name VARCHAR(255) NOT NULL,
player_ip INET,
punishment_type VARCHAR(50) NOT NULL CHECK (punishment_type IN ('BAN', 'MUTE', 'KICK', 'WARN', 'TEMPBAN', 'TEMPMUTE')),
reason TEXT NOT NULL,
staff_uuid VARCHAR(36) NOT NULL,
staff_name VARCHAR(255) NOT NULL,
expires_at TIMESTAMP WITH TIME ZONE,
is_active BOOLEAN DEFAULT true,
revoked_at TIMESTAMP WITH TIME ZONE,
revoked_by VARCHAR(36),
revoked_reason TEXT,
evidence_url TEXT,
notes TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
FOREIGN KEY (player_uuid) REFERENCES luckperms_players(uuid) ON DELETE CASCADE,
FOREIGN KEY (staff_uuid) REFERENCES luckperms_players(uuid) ON DELETE SET NULL,
FOREIGN KEY (revoked_by) REFERENCES luckperms_players(uuid) ON DELETE SET NULL
);
-- Индексы для hub_punishments
CREATE INDEX IF NOT EXISTS idx_hub_punishments_player_uuid ON hub_punishments(player_uuid);
CREATE INDEX IF NOT EXISTS idx_hub_punishments_player_active ON hub_punishments(player_uuid, is_active) WHERE is_active = true;
CREATE INDEX IF NOT EXISTS idx_hub_punishments_type_active ON hub_punishments(punishment_type, is_active) WHERE is_active = true;
CREATE INDEX IF NOT EXISTS idx_hub_punishments_player_ip ON hub_punishments(player_ip) WHERE player_ip IS NOT NULL;
-- Таблица варпов
CREATE TABLE IF NOT EXISTS hub_warps (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name VARCHAR(255) NOT NULL UNIQUE,
world TEXT NOT NULL,
x DOUBLE PRECISION NOT NULL,
y DOUBLE PRECISION NOT NULL,
z DOUBLE PRECISION NOT NULL,
yaw REAL DEFAULT 0.0,
pitch REAL DEFAULT 0.0,
is_public BOOLEAN DEFAULT true,
description VARCHAR(500),
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- Индексы для hub_warps
CREATE INDEX IF NOT EXISTS idx_hub_warps_name ON hub_warps(name);
CREATE INDEX IF NOT EXISTS idx_hub_warps_world ON hub_warps(world);
CREATE INDEX IF NOT EXISTS idx_hub_warps_public ON hub_warps(is_public) WHERE is_public = true;
-- Таблица вайтлиста (ДОПОЛНЕНО)
CREATE TABLE IF NOT EXISTS hub_whitelist (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
player_name VARCHAR(255) NOT NULL UNIQUE,
player_uuid VARCHAR(36),
added_by VARCHAR(255) NOT NULL,
added_at TIMESTAMP WITH TIME ZONE NOT NULL,
expires_at TIMESTAMP WITH TIME ZONE,
is_active BOOLEAN DEFAULT true,
reason VARCHAR(500),
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
FOREIGN KEY (player_uuid) REFERENCES luckperms_players(uuid) ON DELETE SET NULL
);
-- Индексы для hub_whitelist
CREATE INDEX IF NOT EXISTS idx_hub_whitelist_player_name ON hub_whitelist(player_name);
CREATE INDEX IF NOT EXISTS idx_hub_whitelist_player_uuid ON hub_whitelist(player_uuid);
CREATE INDEX IF NOT EXISTS idx_hub_whitelist_active ON hub_whitelist(is_active) WHERE is_active = true;
CREATE INDEX IF NOT EXISTS idx_hub_whitelist_expires ON hub_whitelist(expires_at) WHERE expires_at IS NOT NULL;
-- Таблица истории телепортаций
CREATE TABLE IF NOT EXISTS hub_teleport_history (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
player_uuid VARCHAR(36) NOT NULL,
from_world TEXT,
from_x DOUBLE PRECISION,
from_y DOUBLE PRECISION,
from_z DOUBLE PRECISION,
to_world TEXT NOT NULL,
to_x DOUBLE PRECISION NOT NULL,
to_y DOUBLE PRECISION NOT NULL,
to_z DOUBLE PRECISION NOT NULL,
tp_type VARCHAR(50) NOT NULL,
target_name VARCHAR(255),
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() NOT NULL,
FOREIGN KEY (player_uuid) REFERENCES luckperms_players(uuid) ON DELETE CASCADE
);
-- Индексы для hub_teleport_history
CREATE INDEX IF NOT EXISTS idx_hub_teleport_history_player_uuid ON hub_teleport_history(player_uuid);
CREATE INDEX IF NOT EXISTS idx_hub_teleport_history_created_at ON hub_teleport_history(created_at);
CREATE INDEX IF NOT EXISTS idx_hub_teleport_history_tp_type ON hub_teleport_history(tp_type);
-- ============================================================
-- TRIGGERS
-- ============================================================
-- Функция для автоматического обновления updated_at
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = NOW();
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Применение триггеров ко всем таблицам
DROP TRIGGER IF EXISTS update_luckperms_players_updated_at ON luckperms_players;
CREATE TRIGGER update_luckperms_players_updated_at
BEFORE UPDATE ON luckperms_players
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
DROP TRIGGER IF EXISTS update_luckperms_groups_updated_at ON luckperms_groups;
CREATE TRIGGER update_luckperms_groups_updated_at
BEFORE UPDATE ON luckperms_groups
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
DROP TRIGGER IF EXISTS update_luckperms_user_permissions_updated_at ON luckperms_user_permissions;
CREATE TRIGGER update_luckperms_user_permissions_updated_at
BEFORE UPDATE ON luckperms_user_permissions
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
DROP TRIGGER IF EXISTS update_hub_cooldowns_updated_at ON hub_cooldowns;
CREATE TRIGGER update_hub_cooldowns_updated_at
BEFORE UPDATE ON hub_cooldowns
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
DROP TRIGGER IF EXISTS update_hub_homes_updated_at ON hub_homes;
CREATE TRIGGER update_hub_homes_updated_at
BEFORE UPDATE ON hub_homes
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
DROP TRIGGER IF EXISTS update_hub_punishments_updated_at ON hub_punishments;
CREATE TRIGGER update_hub_punishments_updated_at
BEFORE UPDATE ON hub_punishments
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
DROP TRIGGER IF EXISTS update_hub_warps_updated_at ON hub_warps;
CREATE TRIGGER update_hub_warps_updated_at
BEFORE UPDATE ON hub_warps
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
DROP TRIGGER IF EXISTS update_hub_whitelist_updated_at ON hub_whitelist;
CREATE TRIGGER update_hub_whitelist_updated_at
BEFORE UPDATE ON hub_whitelist
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
-- ============================================================
-- COMMENTS
-- ============================================================
COMMENT ON TABLE luckperms_players IS 'LuckPerms player data';
COMMENT ON TABLE luckperms_groups IS 'LuckPerms permission groups';
COMMENT ON TABLE luckperms_user_permissions IS 'Individual player permissions';
COMMENT ON TABLE hub_cooldowns IS 'Player cooldowns for various actions';
COMMENT ON TABLE hub_homes IS 'Player home locations';
COMMENT ON TABLE hub_punishments IS 'Player punishments (bans, mutes, etc.)';
COMMENT ON TABLE hub_warps IS 'Server warp points';
COMMENT ON TABLE hub_whitelist IS 'Server whitelist entries';
COMMENT ON TABLE hub_teleport_history IS 'History of all player teleportations';
COMMENT ON COLUMN hub_cooldowns.cooldown_type IS 'Type of cooldown: TP_DELAY, HOME_SET, COMBAT, etc.';
COMMENT ON COLUMN hub_cooldowns.metadata IS 'Additional data in JSON format';
COMMENT ON COLUMN hub_punishments.player_ip IS 'Player IP address for IP bans';
COMMENT ON COLUMN hub_punishments.evidence_url IS 'URL to evidence (screenshot, video, etc.)';
COMMENT ON COLUMN hub_punishments.notes IS 'Internal moderator notes';
COMMENT ON COLUMN hub_whitelist.expires_at IS 'Expiration date for temporary whitelist';
COMMENT ON COLUMN hub_whitelist.is_active IS 'Whether whitelist entry is currently active';
COMMENT ON COLUMN hub_teleport_history.tp_type IS 'Type of teleport: HOME, WARP, TPA, TPAHERE, SPAWN, BACK, etc.';
COMMENT ON COLUMN hub_teleport_history.target_name IS 'Target name for TPA/home/warp teleports';

View File

@ -8,7 +8,7 @@ from hubgw.models.base import Base
class Cooldown(Base):
"""Cooldown model."""
__tablename__ = "cooldowns"
__tablename__ = "hub_cooldowns"
id = Column(UUID(as_uuid=True), primary_key=True)
key = Column(String(255), nullable=False, unique=True, index=True)

View File

@ -8,7 +8,7 @@ from hubgw.models.base import Base
class Home(Base):
"""Home model."""
__tablename__ = "homes"
__tablename__ = "hub_homes"
id = Column(UUID(as_uuid=True), primary_key=True)
player_uuid = Column(UUID(as_uuid=True), nullable=False, index=True)

View File

@ -8,7 +8,7 @@ from hubgw.models.base import Base
class Punishment(Base):
"""Punishment model."""
__tablename__ = "punishments"
__tablename__ = "hub_punishments"
id = Column(UUID(as_uuid=True), primary_key=True)
player_uuid = Column(UUID(as_uuid=True), nullable=False, index=True)

View File

@ -8,7 +8,7 @@ from hubgw.models.base import Base
class Warp(Base):
"""Warp model."""
__tablename__ = "warps"
__tablename__ = "hub_warps"
id = Column(UUID(as_uuid=True), primary_key=True)
name = Column(String(255), nullable=False, unique=True, index=True)

View File

@ -8,7 +8,7 @@ from hubgw.models.base import Base
class WhitelistEntry(Base):
"""Whitelist entry model."""
__tablename__ = "whitelist"
__tablename__ = "hub_whitelist"
id = Column(UUID(as_uuid=True), primary_key=True)
player_name = Column(String(255), nullable=False, unique=True, index=True)