-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates control tables
--
-- Copyright(C) 2004-2012, DeepClone Development
-- --------------------------------------------------------


/*
 * Update targets
 * ---------------
 * 
 * An update target refers to a table whose rows are the units to be updated
 * by some step of the game update.
 * 
 * Inserting rows into this control table will generate a new, specific table
 * to store references, and a set of triggers.
 */
DROP TABLE IF EXISTS sys.update_targets CASCADE;
CREATE TABLE sys.update_targets(
	/* Automatically generated identifier of the target type */
	updtgt_id			SERIAL NOT NULL PRIMARY KEY ,
	
	/* Name of the target, displayed in the administration interface */
	updtgt_name			VARCHAR( 32 ) NOT NULL ,

	/* Schema in which the target table resides */
	updtgt_schema		NAME NOT NULL ,

	/* Name of the target table */
	updtgt_table		NAME NOT NULL
);

/* Update target names are unique */
CREATE UNIQUE INDEX idx_updtgt_name
	ON sys.update_targets ( LOWER( updtgt_name ) );
/* Schema / table combinations are unique */
CREATE UNIQUE INDEX idx_updtgt_target
	ON sys.update_targets ( updtgt_schema , updtgt_table );



/*
 * Update type definitions
 * ------------------------
 * 
 * An update type corresponds to a procedure which will be applied at each
 * game update cycle (once per minute, unless defaults have been modified),
 * and which performs a computation or set thereof on the game's data.
 */
DROP TABLE IF EXISTS sys.update_types CASCADE;
CREATE TABLE sys.update_types(
	/* Automatically generated identifier of the update type */
	updtype_id			SERIAL NOT NULL ,

	/* The type of target this update refers to */
	updtgt_id			INT NOT NULL ,
	
	/* Name of the update type, used in the administration interface and when
	 * updates need to be executed externally.
	 */
	updtype_name		VARCHAR( 64 ) NOT NULL ,

	/* Ordering index of the update type. This field is always re-generated
	 * when update types are added or removed.
	 */
	updtype_ordering	INT NOT NULL ,

	/* Description of the update type to be included in the administration
	 * interface.
	 */
	updtype_description	TEXT NOT NULL ,
	
	/* Name of the stored procedure which handles the update. When this is
	 * NULL, the update type is assumed to be supported externally (i.e. by
	 * the game server) rather than internally. Otherwise, a stored procedure
	 * bearing that name, accepting a BIGINT as its parameter and returning
	 * VOID, must exist in the sys schema. 
	 */
	updtype_proc_name	NAME ,

	/* Size of the update batch. If this is NULL, the global value from the
	 * game.batchSize constant will be used.
	 */
	updtype_batch_size	INT ,

	/* The primary key includes both the update type identifier and the target
	 * identifier for coherence reasons.
	 */
	PRIMARY KEY( updtype_id , updtgt_id ) ,

	/* Batch sizes are either NULL or strictly positive */
	CHECK( updtype_batch_size IS NULL
			OR updtype_batch_size > 0 )
);

/* Update names must be unique, independently of the case */
CREATE UNIQUE INDEX idx_updtype_name
	ON sys.update_types ( LOWER( updtype_name ) );
/* Update ordering index must be unique */
CREATE UNIQUE INDEX idx_updtype_ordering
	ON sys.update_types ( updtype_ordering );
/* Procedure names must be unique */
CREATE UNIQUE INDEX idx_updtype_procname
	ON sys.update_types ( updtype_proc_name );



ALTER TABLE sys.update_types
	ADD CONSTRAINT fk_updtype_target
		FOREIGN KEY ( updtgt_id ) REFERENCES sys.update_targets( updtgt_id );



/*
 * Update state type
 * ------------------
 * 
 * This type represents the possible states of a game update
 */
DROP TYPE IF EXISTS sys.update_state_type CASCADE;
CREATE TYPE sys.update_state_type
	AS ENUM (
		/* The row will be included in the current game update */
		'FUTURE' ,
		/* The row is being processed */
		'PROCESSING' ,
		/* The row has been processed by the current or previous game update */
		'PROCESSED'
	);


/*
 * Main updates table
 * -------------------
 * 
 * This table lists all update rows, including their type and target, as well
 * as their state.
 */
DROP TABLE IF EXISTS sys.updates CASCADE;
CREATE TABLE sys.updates(
	/* The update row's automatically generated identifier */
	update_id		BIGSERIAL NOT NULL ,

	/* The type of update this row is about */
	updtype_id		INT NOT NULL ,

	/* The type of target for the update */
	updtgt_id		INT NOT NULL ,

	/* The update row's current state */
	update_state	sys.update_state_type
						NOT NULL
						DEFAULT 'FUTURE' ,

	/* The tick identifier corresponding to the last game update in which
	 * this row was processed.
	 */
	update_last		BIGINT NOT NULL
						DEFAULT -1 ,

	/* The primary key includes the automatically generated identifier but
	 * also the type and target type.
	 */
	PRIMARY KEY( update_id , updtype_id , updtgt_id )
);

ALTER TABLE sys.updates
	ADD CONSTRAINT fk_update_type
		FOREIGN KEY ( updtype_id , updtgt_id ) REFERENCES sys.update_types
			ON DELETE CASCADE;