This repository has been archived on 2024-07-18. You can view files and clone it, but cannot push or open issues or pull requests.
lwb6/legacyworlds-server/legacyworlds-server-data/db-structure/parts/data/040-admin-data.sql

170 lines
4.2 KiB
MySQL
Raw Normal View History

2018-10-23 09:38:02 +02:00
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Administrative tables
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
--
-- Administrators
--
CREATE TABLE admin.administrators(
id SERIAL NOT NULL PRIMARY KEY ,
appear_as VARCHAR( 48 ) NOT NULL ,
pass_md5 CHAR(32) NOT NULL ,
pass_sha1 CHAR(40) NOT NULL ,
privileges INT NOT NULL
);
CREATE UNIQUE INDEX idx_administrators_appearas
ON admin.administrators( lower(appear_as) );
--
-- Administrators <-> credentials
--
CREATE TABLE admin.admin_credentials(
administrator_id INT NOT NULL ,
credentials_id INT NOT NULL ,
PRIMARY KEY(administrator_id)
);
CREATE UNIQUE INDEX idx_admincreds_creds
ON admin.admin_credentials( credentials_id );
ALTER TABLE admin.admin_credentials
ADD CONSTRAINT fk_admincreds_admin
FOREIGN KEY (administrator_id) REFERENCES admin.administrators ,
ADD CONSTRAINT fk_admincreds_creds
FOREIGN KEY (credentials_id) REFERENCES users.credentials
ON UPDATE CASCADE;
--
-- Ban requests
--
CREATE TABLE admin.ban_requests(
id SERIAL NOT NULL PRIMARY KEY ,
requested_by INT NOT NULL ,
reason TEXT NOT NULL ,
requested TIMESTAMP WITHOUT TIME ZONE
NOT NULL
DEFAULT now()
);
CREATE INDEX idx_banrequests_requestedby
ON admin.ban_requests( requested_by );
ALTER TABLE admin.ban_requests
ADD CONSTRAINT fk_banrequests_requestedby
FOREIGN KEY (requested_by) REFERENCES admin.administrators;
--
-- Active ban requests
--
CREATE TABLE admin.active_ban_requests(
request_id INT NOT NULL PRIMARY KEY ,
credentials_id INT NOT NULL ,
validated BOOLEAN NOT NULL
DEFAULT FALSE
);
CREATE UNIQUE INDEX idx_activebanrequests_creds
ON admin.active_ban_requests (credentials_id);
ALTER TABLE admin.active_ban_requests
ADD CONSTRAINT fk_activebanrequests_request
FOREIGN KEY (request_id) REFERENCES admin.ban_requests ,
ADD CONSTRAINT fk_activebanrequests_creds
FOREIGN KEY (credentials_id) REFERENCES users.credentials
ON DELETE CASCADE ON UPDATE CASCADE;
--
-- Archived ban requests
--
CREATE TABLE admin.archived_ban_requests(
request_id INT NOT NULL PRIMARY KEY ,
credentials_id INT NOT NULL ,
updated TIMESTAMP WITHOUT TIME ZONE
NOT NULL
DEFAULT now()
);
CREATE INDEX idx_archivedbanrequests_creds
ON admin.archived_ban_requests (credentials_id);
ALTER TABLE admin.archived_ban_requests
ADD CONSTRAINT fk_archivedbanrequests_request
FOREIGN KEY (request_id) REFERENCES admin.ban_requests ,
ADD CONSTRAINT fk_archivedbanrequests_creds
FOREIGN KEY (credentials_id) REFERENCES users.credentials
ON DELETE CASCADE ON UPDATE CASCADE;
--
-- Rejected ban requests
--
CREATE TABLE admin.rejected_ban_requests(
request_id INT NOT NULL PRIMARY KEY ,
rejected_by INT NOT NULL ,
reason TEXT NOT NULL
);
CREATE INDEX idx_rejectedbanrequests_rejected
ON admin.rejected_ban_requests (rejected_by);
ALTER TABLE admin.rejected_ban_requests
ADD CONSTRAINT fk_rejectedbanrequests_request
FOREIGN KEY (request_id) REFERENCES admin.ban_requests ,
ADD CONSTRAINT fk_rejectedbanrequests_rejected
FOREIGN KEY (rejected_by) REFERENCES admin.administrators;
--
-- Validated ban requests
--
CREATE TABLE admin.validated_ban_requests(
request_id INT NOT NULL PRIMARY KEY ,
validated_by INT NOT NULL ,
validated TIMESTAMP WITHOUT TIME ZONE
NOT NULL
DEFAULT now( )
);
CREATE INDEX idx_validatedbanrequests_validated
ON admin.validated_ban_requests (validated_by);
ALTER TABLE admin.validated_ban_requests
ADD CONSTRAINT fk_validatedbanrequests_request
FOREIGN KEY (request_id) REFERENCES admin.ban_requests ,
ADD CONSTRAINT fk_validatedbanrequests_rejected
FOREIGN KEY (validated_by) REFERENCES admin.administrators;
--
-- Warnings to users
--
CREATE TABLE admin.warnings (
credentials_id INT NOT NULL PRIMARY KEY ,
warnings INT NOT NULL
DEFAULT 1
CHECK( warnings >= 0 ) ,
last_received TIMESTAMP WITHOUT TIME ZONE
NOT NULL
DEFAULT now( )
);
CREATE INDEX idx_warnings_received
ON admin.warnings( last_received )
WHERE warnings > 0;
ALTER TABLE admin.warnings
ADD CONSTRAINT fk_warnings_credentials
FOREIGN KEY ( credentials_id ) REFERENCES users.credentials
ON UPDATE CASCADE ON DELETE CASCADE;