235 lines
5.8 KiB
MySQL
235 lines
5.8 KiB
MySQL
|
-- LegacyWorlds Beta 6
|
||
|
-- PostgreSQL database scripts
|
||
|
--
|
||
|
-- Storage of messages
|
||
|
--
|
||
|
-- Copyright(C) 2004-2010, DeepClone Development
|
||
|
-- --------------------------------------------------------
|
||
|
|
||
|
|
||
|
CREATE TYPE sender_type
|
||
|
AS ENUM( 'ADM', 'EMP' );
|
||
|
|
||
|
CREATE TYPE receiver_type
|
||
|
AS ENUM( 'ADM' , 'EMP' , 'ALL' );
|
||
|
|
||
|
CREATE TYPE message_status
|
||
|
AS ENUM( 'UNREAD' , 'READ' , 'DELETED' );
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Message senders
|
||
|
--
|
||
|
|
||
|
CREATE TABLE msgs.senders(
|
||
|
id BIGSERIAL PRIMARY KEY ,
|
||
|
sender_type sender_type NOT NULL ,
|
||
|
name VARCHAR(48) NOT NULL ,
|
||
|
empire_id INT ,
|
||
|
admin_id INT ,
|
||
|
CHECK ( empire_id IS NULL AND admin_id IS NULL
|
||
|
OR sender_type = 'ADM' AND empire_id IS NULL AND admin_id IS NOT NULL
|
||
|
OR sender_type = 'EMP' AND empire_id IS NOT NULL AND admin_id IS NULL )
|
||
|
);
|
||
|
|
||
|
CREATE UNIQUE INDEX idx_senders_empires
|
||
|
ON msgs.senders ( empire_id )
|
||
|
WHERE empire_id IS NOT NULL;
|
||
|
|
||
|
CREATE UNIQUE INDEX idx_senders_admins
|
||
|
ON msgs.senders ( admin_id )
|
||
|
WHERE admin_id IS NOT NULL;
|
||
|
|
||
|
ALTER TABLE msgs.senders
|
||
|
ADD CONSTRAINT fk_senders_empire
|
||
|
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||
|
ON DELETE SET NULL ,
|
||
|
ADD CONSTRAINT fk_senders_admin
|
||
|
FOREIGN KEY ( admin_id ) REFERENCES admin.administrators
|
||
|
ON DELETE SET NULL;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Message receivers
|
||
|
--
|
||
|
|
||
|
CREATE TABLE msgs.receivers(
|
||
|
id BIGSERIAL PRIMARY KEY ,
|
||
|
receiver_type receiver_type NOT NULL ,
|
||
|
name VARCHAR(48) NOT NULL ,
|
||
|
empire_id INT ,
|
||
|
admin_id INT ,
|
||
|
alliance_id INT ,
|
||
|
CHECK ( empire_id IS NULL AND admin_id IS NULL AND alliance_id IS NULL
|
||
|
OR receiver_type = 'ADM' AND empire_id IS NULL AND admin_id IS NOT NULL AND alliance_id IS NULL
|
||
|
OR receiver_type = 'EMP' AND empire_id IS NOT NULL AND admin_id IS NULL AND alliance_id IS NULL
|
||
|
OR receiver_type = 'ALL' AND empire_id IS NULL AND admin_id IS NULL AND alliance_id IS NOT NULL )
|
||
|
);
|
||
|
|
||
|
CREATE UNIQUE INDEX idx_receivers_empires
|
||
|
ON msgs.receivers ( empire_id )
|
||
|
WHERE empire_id IS NOT NULL;
|
||
|
|
||
|
CREATE UNIQUE INDEX idx_receivers_admins
|
||
|
ON msgs.receivers ( admin_id )
|
||
|
WHERE admin_id IS NOT NULL;
|
||
|
|
||
|
CREATE UNIQUE INDEX idx_receivers_alliances
|
||
|
ON msgs.receivers ( alliance_id )
|
||
|
WHERE alliance_id IS NOT NULL;
|
||
|
|
||
|
ALTER TABLE msgs.receivers
|
||
|
ADD CONSTRAINT fk_receivers_empire
|
||
|
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||
|
ON DELETE SET NULL ,
|
||
|
ADD CONSTRAINT fk_receivers_alliance
|
||
|
FOREIGN KEY ( alliance_id ) REFERENCES emp.alliances
|
||
|
ON DELETE SET NULL ,
|
||
|
ADD CONSTRAINT fk_receivers_admin
|
||
|
FOREIGN KEY ( admin_id ) REFERENCES admin.administrators
|
||
|
ON DELETE SET NULL;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Text messages
|
||
|
--
|
||
|
|
||
|
CREATE TABLE msgs.text_messages(
|
||
|
id BIGSERIAL PRIMARY KEY ,
|
||
|
tick BIGINT NOT NULL ,
|
||
|
t TIMESTAMP WITHOUT TIME ZONE
|
||
|
NOT NULL DEFAULT now( ) ,
|
||
|
title VARCHAR( 64 ) NOT NULL ,
|
||
|
contents TEXT NOT NULL
|
||
|
);
|
||
|
|
||
|
GRANT SELECT ON msgs.text_messages TO :dbuser;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Actual messages
|
||
|
--
|
||
|
|
||
|
CREATE TABLE msgs.messages(
|
||
|
id BIGSERIAL PRIMARY KEY ,
|
||
|
receiver_id BIGINT NOT NULL ,
|
||
|
sender_id BIGINT ,
|
||
|
text_content_id BIGINT ,
|
||
|
event_content_id BIGINT ,
|
||
|
CHECK(
|
||
|
sender_id IS NULL AND text_content_id IS NULL AND event_content_id IS NOT NULL
|
||
|
OR sender_id IS NOT NULL AND text_content_id IS NOT NULL AND event_content_id IS NULL )
|
||
|
);
|
||
|
|
||
|
CREATE INDEX idx_messages_receiver
|
||
|
ON msgs.messages( receiver_id );
|
||
|
|
||
|
CREATE UNIQUE INDEX idx_messages_e_event
|
||
|
ON msgs.messages( event_content_id )
|
||
|
WHERE event_content_id IS NOT NULL;
|
||
|
|
||
|
CREATE INDEX idx_messages_sender
|
||
|
ON msgs.messages( sender_id )
|
||
|
WHERE sender_id IS NOT NULL;
|
||
|
|
||
|
CREATE INDEX idx_messages_t_text
|
||
|
ON msgs.messages( text_content_id )
|
||
|
WHERE text_content_id IS NOT NULL;
|
||
|
|
||
|
ALTER TABLE msgs.messages
|
||
|
ADD CONSTRAINT fk_messages_receiver
|
||
|
FOREIGN KEY ( receiver_id ) REFERENCES msgs.receivers ,
|
||
|
ADD CONSTRAINT fk_messages_sender
|
||
|
FOREIGN KEY ( sender_id ) REFERENCES msgs.senders ,
|
||
|
ADD CONSTRAINT fk_messages_text
|
||
|
FOREIGN KEY ( text_content_id ) REFERENCES msgs.text_messages ,
|
||
|
ADD CONSTRAINT fk_messages_event
|
||
|
FOREIGN KEY ( event_content_id ) REFERENCES events.events
|
||
|
ON DELETE CASCADE;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Empire message delivery
|
||
|
--
|
||
|
|
||
|
CREATE TABLE msgs.empire_delivery(
|
||
|
id BIGSERIAL PRIMARY KEY ,
|
||
|
empire_id INT NOT NULL ,
|
||
|
message_id BIGINT NOT NULL ,
|
||
|
in_inbox BOOLEAN NOT NULL ,
|
||
|
status message_status NOT NULL ,
|
||
|
emailed BOOLEAN NOT NULL ,
|
||
|
recaped BOOLEAN NOT NULL
|
||
|
);
|
||
|
|
||
|
CREATE INDEX idx_edelivery_empire
|
||
|
ON msgs.empire_delivery ( empire_id );
|
||
|
|
||
|
CREATE UNIQUE INDEX idx_edelivery_message
|
||
|
ON msgs.empire_delivery ( message_id , empire_id , in_inbox );
|
||
|
|
||
|
CREATE INDEX idx_edelivery_access
|
||
|
ON msgs.empire_delivery ( empire_id , in_inbox , status );
|
||
|
|
||
|
CREATE INDEX idx_edelivery_status
|
||
|
ON msgs.empire_delivery ( status , emailed , recaped );
|
||
|
|
||
|
ALTER TABLE msgs.empire_delivery
|
||
|
ADD CONSTRAINT fk_edelivery_empire
|
||
|
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||
|
ON DELETE CASCADE ,
|
||
|
ADD CONSTRAINT fk_edelivery_message
|
||
|
FOREIGN KEY ( message_id ) REFERENCES msgs.messages
|
||
|
ON DELETE CASCADE;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Admin message delivery
|
||
|
--
|
||
|
|
||
|
CREATE TABLE msgs.admin_delivery(
|
||
|
id BIGSERIAL PRIMARY KEY ,
|
||
|
admin_id INT NOT NULL ,
|
||
|
message_id BIGINT NOT NULL ,
|
||
|
in_inbox BOOLEAN NOT NULL ,
|
||
|
status message_status NOT NULL ,
|
||
|
emailed BOOLEAN NOT NULL
|
||
|
);
|
||
|
|
||
|
CREATE INDEX idx_adelivery_admin
|
||
|
ON msgs.admin_delivery ( admin_id );
|
||
|
|
||
|
CREATE INDEX idx_adelivery_message
|
||
|
ON msgs.admin_delivery ( message_id );
|
||
|
|
||
|
CREATE INDEX idx_adelivery_status
|
||
|
ON msgs.admin_delivery ( status , emailed );
|
||
|
|
||
|
ALTER TABLE msgs.admin_delivery
|
||
|
ADD CONSTRAINT fk_adelivery_admin
|
||
|
FOREIGN KEY ( admin_id ) REFERENCES admin.administrators
|
||
|
ON DELETE CASCADE ,
|
||
|
ADD CONSTRAINT fk_adelivery_message
|
||
|
FOREIGN KEY ( message_id ) REFERENCES msgs.messages;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- E-mail notification status
|
||
|
--
|
||
|
|
||
|
CREATE TABLE msgs.email_notifications(
|
||
|
account_id INT PRIMARY KEY ,
|
||
|
last_sent TIMESTAMP WITHOUT TIME ZONE
|
||
|
NOT NULL DEFAULT now()
|
||
|
);
|
||
|
|
||
|
ALTER TABLE msgs.email_notifications
|
||
|
ADD CONSTRAINT fk_emailnotifications_account
|
||
|
FOREIGN KEY ( account_id ) REFERENCES users.active_accounts
|
||
|
ON DELETE CASCADE ON UPDATE CASCADE;
|