109 lines
2.4 KiB
SQL
109 lines
2.4 KiB
SQL
-- LegacyWorlds Beta 6
|
|
-- PostgreSQL database scripts
|
|
--
|
|
-- Empire/map object names
|
|
--
|
|
-- Copyright(C) 2004-2010, DeepClone Development
|
|
-- --------------------------------------------------------
|
|
|
|
|
|
--
|
|
-- Banned names
|
|
--
|
|
|
|
CREATE TABLE naming.banned_names(
|
|
name VARCHAR(20) NOT NULL ,
|
|
added_by INT NOT NULL
|
|
);
|
|
|
|
CREATE UNIQUE INDEX idx_bannednames_name
|
|
ON naming.banned_names( lower(name) );
|
|
CREATE INDEX idx_bannednames_addedby
|
|
ON naming.banned_names (added_by);
|
|
|
|
ALTER TABLE naming.banned_names
|
|
ADD CONSTRAINT fk_bannednames_addedby
|
|
FOREIGN KEY (added_by) REFERENCES admin.administrators;
|
|
|
|
|
|
--
|
|
-- Empire names
|
|
--
|
|
|
|
CREATE TABLE naming.empire_names (
|
|
id SERIAL NOT NULL PRIMARY KEY ,
|
|
owner_id INT NOT NULL ,
|
|
name VARCHAR(20) NOT NULL
|
|
);
|
|
|
|
CREATE UNIQUE INDEX idx_empirenames_name
|
|
ON naming.empire_names( lower(name) );
|
|
CREATE INDEX idx_empirenames_owner
|
|
ON naming.empire_names( owner_id );
|
|
|
|
ALTER TABLE naming.empire_names
|
|
ADD CONSTRAINT fk_empirenames_owner
|
|
FOREIGN KEY (owner_id) REFERENCES users.credentials
|
|
ON DELETE CASCADE ON UPDATE CASCADE;
|
|
|
|
GRANT SELECT ON naming.empire_names TO :dbuser;
|
|
|
|
|
|
|
|
--
|
|
-- Map names
|
|
--
|
|
CREATE TABLE naming.map_names(
|
|
id SERIAL NOT NULL PRIMARY KEY ,
|
|
name VARCHAR(20) NOT NULL
|
|
);
|
|
|
|
CREATE UNIQUE INDEX idx_mapnames_name
|
|
ON naming.map_names( lower(name) );
|
|
|
|
|
|
--
|
|
-- Changed map names
|
|
--
|
|
|
|
CREATE TABLE naming.changed_map_names(
|
|
name_id INT NOT NULL PRIMARY KEY ,
|
|
named_by INT NOT NULL ,
|
|
named_at TIMESTAMP WITHOUT TIME ZONE
|
|
NOT NULL
|
|
DEFAULT now()
|
|
);
|
|
|
|
CREATE INDEX idx_changedmapnames_namedby
|
|
ON naming.changed_map_names (named_by);
|
|
|
|
ALTER TABLE naming.changed_map_names
|
|
ADD CONSTRAINT fk_changedmapnames_name
|
|
FOREIGN KEY (name_id) REFERENCES naming.map_names ,
|
|
ADD CONSTRAINT fk_changedmapnames_namedby
|
|
FOREIGN KEY (named_by) REFERENCES users.credentials
|
|
ON DELETE CASCADE ON UPDATE CASCADE;
|
|
|
|
|
|
--
|
|
-- Validated map names
|
|
--
|
|
|
|
CREATE TABLE naming.validated_map_names(
|
|
name_id INT NOT NULL PRIMARY KEY ,
|
|
validated_by INT NOT NULL ,
|
|
validated_at TIMESTAMP WITHOUT TIME ZONE
|
|
NOT NULL
|
|
DEFAULT now()
|
|
);
|
|
|
|
CREATE INDEX idx_validatedmapnames_namedby
|
|
ON naming.validated_map_names (validated_by);
|
|
|
|
|
|
ALTER TABLE naming.validated_map_names
|
|
ADD CONSTRAINT fk_validatedmapnames_name
|
|
FOREIGN KEY (name_id) REFERENCES naming.changed_map_names
|
|
ON DELETE CASCADE ,
|
|
ADD CONSTRAINT fk_validatedmapnames_validatedby
|
|
FOREIGN KEY (validated_by) REFERENCES admin.administrators;
|