-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- System, user and administrative logs
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------


--
-- System logs
--
CREATE TABLE sys.logs(
	id				BIGSERIAL NOT NULL PRIMARY KEY ,
	t				TIMESTAMP WITHOUT TIME ZONE
						NOT NULL
						DEFAULT now( ) ,
	component		VARCHAR( 64 ) ,
	level			log_level NOT NULL ,
	message			TEXT NOT NULL
);

CREATE INDEX idx_syslogs_time
	ON sys.logs( t );
CREATE INDEX idx_syslogs_component
	ON sys.logs( component );
CREATE INDEX idx_syslogs_level
	ON sys.logs( level );

GRANT SELECT ON sys.logs TO :dbuser;


--
-- System logs, exceptions
--
CREATE TABLE sys.exceptions(
	id				BIGSERIAL NOT NULL PRIMARY KEY ,
	log_id			BIGINT NOT NULL ,
	depth			INT NOT NULL CHECK( depth>= 0 ) ,
	exc_class		VARCHAR( 255 ) NOT NULL ,
	message			TEXT
);

CREATE UNIQUE INDEX idx_exceptions_logdepth
	ON sys.exceptions (log_id , depth );

ALTER TABLE sys.exceptions
	ADD CONSTRAINT fk_exceptions_log
		FOREIGN KEY ( log_id ) REFERENCES sys.logs
			ON DELETE CASCADE;

GRANT SELECT ON sys.exceptions TO :dbuser;


--
-- System logs, stack traces
--
CREATE TABLE sys.stack_traces(
	exception_id	BIGSERIAL NOT NULL ,
	depth			INT NOT NULL ,
	location		TEXT ,
	file_name		TEXT ,
	line_number		INT ,
	PRIMARY KEY( exception_id , depth )
);

ALTER TABLE sys.stack_traces
	ADD CONSTRAINT fk_stacktraces_exception
		FOREIGN KEY ( exception_id ) REFERENCES sys.exceptions
			ON DELETE CASCADE;

GRANT SELECT ON sys.stack_traces TO :dbuser;


--
-- User logs
--
CREATE TABLE users.logs(
	t				TIMESTAMP WITHOUT TIME ZONE
						NOT NULL
						DEFAULT now( ) ,
	credentials_id	INT NOT NULL ,
	level			log_level NOT NULL ,
	message			TEXT NOT NULL
);

CREATE INDEX idx_userlogs_time
	ON users.logs( t );
CREATE INDEX idx_userlogs_level
	ON users.logs( level );
CREATE INDEX idx_userlogs_account
	ON users.logs( credentials_id );
	
ALTER TABLE users.logs
	ADD CONSTRAINT fk_userlogs_credentials
		FOREIGN KEY (credentials_id) REFERENCES users.credentials
			ON DELETE CASCADE ON UPDATE CASCADE;

GRANT SELECT ON users.logs TO :dbuser;


--
-- Administrative logs
--
CREATE TABLE admin.logs(
	t				TIMESTAMP WITHOUT TIME ZONE
						NOT NULL
						DEFAULT now( ) ,
	admin_id		INT NOT NULL ,
	level			log_level NOT NULL ,
	message			TEXT NOT NULL
);

CREATE INDEX idx_adminlogs_time
	ON admin.logs( t );
CREATE INDEX idx_adminlogs_level
	ON admin.logs( level );
CREATE INDEX idx_adminlogs_admin
	ON admin.logs( admin_id );
	
ALTER TABLE admin.logs
	ADD CONSTRAINT fk_userlogs_admin
		FOREIGN KEY (admin_id) REFERENCES admin.administrators;


GRANT SELECT ON admin.logs TO :dbuser;