Database management changes

* Added in-base logging through a foreign data wrapper, which is only
possible using PostgreSQL 9.1
* Renamed database-related configuration files to indicate that they are
samples, and added the "real" names to the Git ignore list. Server
distribution modified accordingly.
* Removed PL/PgSQL registration (it was only necessary on 8.4)
* Added pgTAP SQL definitions and a script which will (hopefully) be
executed by the build system after the main Java build in order to
execute database unit tests. The script supports both admin- and user-
level testing. I also added a few tests to make sure the testing framework
actually runs them.
* Added documentation about the database definitions structure
This commit is contained in:
Emmanuel BENOîT 2011-12-15 15:38:46 +01:00
parent f682594cbd
commit be3106c463
18 changed files with 7669 additions and 47 deletions

View file

@ -12,7 +12,9 @@
-- Read configuration from file
\set pgadmin `grep ^admin= db-config.txt | sed -e s/.*=//`
\set dbname `grep ^db= db-config.txt | sed -e s/.*=//`
\set dbname_string '''':dbname''''
\set dbuser `grep ^user= db-config.txt | sed -e s/.*=//`
\set dbuser_string '''':dbuser''''
\set dbupass ''''`grep ^password= db-config.txt | sed -e s/.*=// -e "s/'/''/g"`''''
@ -34,8 +36,21 @@ GRANT CONNECT ON DATABASE :dbname TO :dbuser;
-- Connect to the LW database with the PostgreSQL admin user
\c :dbname :pgadmin
-- Register PL/PgSQL
CREATE TRUSTED PROCEDURAL LANGUAGE plpgsql;
-- Register the dblink extension
CREATE EXTENSION dblink;
-- Create foreign data wrapper and server used to write logs from within
-- transanctions
CREATE FOREIGN DATA WRAPPER pgsql
VALIDATOR postgresql_fdw_validator;
CREATE SERVER srv_logging
FOREIGN DATA WRAPPER pgsql
OPTIONS ( hostaddr '127.0.0.1' , dbname :dbname_string );
CREATE USER MAPPING FOR :dbuser
SERVER srv_logging
OPTIONS ( user :dbuser_string , password :dbupass );
GRANT USAGE ON FOREIGN SERVER srv_logging TO :dbuser;
BEGIN;

View file

@ -61,7 +61,7 @@ BEGIN
THEN
UPDATE sys.ticker SET status = 'RUNNING' , auto_start = NULL
WHERE id = task_id;
PERFORM sys.write_log( 'Ticker' , 'INFO'::log_level , 'Scheduled task ''' || t_name
PERFORM sys.write_sql_log( 'Ticker' , 'INFO'::log_level , 'Scheduled task ''' || t_name
|| ''' has been enabled' );
END IF;
END;

View file

@ -124,6 +124,42 @@ $$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.write_log( TEXT , log_level , TEXT ) TO :dbuser;
--
-- Remotely append a system log entry
--
-- This function is called from within transactions in order to write to the
-- system log. Unlike sys.write_log(), entries added through this function
-- will not be lost if the transaction is rolled back.
--
-- Since the function is meant to be called from SQL code, it does not return
-- anything as the identifier of the new entry is not required.
--
-- Parameters:
-- _component The component that is appending to the log
-- _level The log level
-- _message The message to write
--
CREATE OR REPLACE FUNCTION sys.write_sql_log( _component TEXT , _level log_level , _message TEXT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $write_sql_log$
BEGIN
PERFORM dblink_connect( 'cn_logging' , 'srv_logging' );
PERFORM * FROM dblink( 'cn_logging' ,
'SELECT * FROM sys.write_log( '
|| quote_literal( _component ) || ' , '''
|| _level::text || '''::log_level , '
|| quote_literal( _message ) || ' )'
) AS ( entry_id bigint );
PERFORM dblink_disconnect( 'cn_logging' );
END;
$write_sql_log$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.write_sql_log( TEXT , log_level , TEXT ) TO :dbuser;
--
-- Append an exception log entry

View file

@ -181,7 +181,7 @@ BEGIN
ELSE
RAISE EXCEPTION 'Invalid account status % (account #%)' , st , a_id;
END IF;
PERFORM sys.write_log( 'AccountManagement' , 'ERROR'::log_level , 'Account re-activation mail could not be sent for account #' || a_id || ', deleting validation key' );
PERFORM sys.write_sql_log( 'AccountManagement' , 'ERROR'::log_level , 'Account re-activation mail could not be sent for account #' || a_id || ', deleting validation key' );
END;
$$ LANGUAGE plpgsql;
@ -470,7 +470,7 @@ BEGIN
WHERE a.address = addr
FOR UPDATE;
IF NOT FOUND THEN
PERFORM sys.write_log( 'AccountManagement' , 'WARNING'::log_level , 'account for "'
PERFORM sys.write_sql_log( 'AccountManagement' , 'WARNING'::log_level , 'account for "'
|| addr || '" not found' );
account_error := 1;
RETURN;

View file

@ -990,7 +990,7 @@ DECLARE
st_dmg REAL;
n_dest INT;
BEGIN
PERFORM sys.write_log( 'BattleUpdate' , 'TRACE'::log_level , 'Inflicting ' || dmg
PERFORM sys.write_sql_log( 'BattleUpdate' , 'TRACE'::log_level , 'Inflicting ' || dmg
|| ' damage to planet #' || p_id );
bp_id := NULL;
@ -1008,7 +1008,7 @@ BEGIN
st_dmg := 0;
END IF;
PERFORM sys.write_log( 'BattleUpdate' , 'TRACE'::log_level , 'Building type #' || rec.building_id
PERFORM sys.write_sql_log( 'BattleUpdate' , 'TRACE'::log_level , 'Building type #' || rec.building_id
|| ' - Damage ' || st_dmg || '; destruction: ' || n_dest );
-- Apply damage
@ -1054,7 +1054,7 @@ DECLARE
BEGIN
tick := sys.get_tick( ) - 1;
tot_damage := t_upkeep * d_ratio / debt;
PERFORM sys.write_log( 'EmpireDebt' , 'DEBUG'::log_level , 'Inflicting debt damage to buildings; total upkeep: '
PERFORM sys.write_sql_log( 'EmpireDebt' , 'DEBUG'::log_level , 'Inflicting debt damage to buildings; total upkeep: '
|| t_upkeep || ', damage ratio: ' || d_ratio || ', total damage: ' || tot_damage );
FOR p_rec IN SELECT ep.planet_id AS planet , b.id AS battle

View file

@ -653,7 +653,7 @@ BEGIN
IF NOT att THEN
st_power := battles.get_defence_power( b_id , tick );
tot_power := tot_power + st_power;
PERFORM sys.write_log( 'BattleUpdate' , 'TRACE'::log_level , 'About to inflict planet damage; total power: ' || tot_power
PERFORM sys.write_sql_log( 'BattleUpdate' , 'TRACE'::log_level , 'About to inflict planet damage; total power: ' || tot_power
|| '; planet power: ' || st_power || '; computed damage: ' || ( dmg * st_power / tot_power )::REAL );
IF st_power <> 0 THEN
PERFORM verse.inflict_battle_damage( planet , st_power , ( dmg * st_power / tot_power )::REAL , b_id , tick );

View file

@ -415,17 +415,17 @@ BEGIN
-- Fleet redirection
IF rec.is_ref_point IS NULL THEN
-- Fleet moving in outer space
PERFORM sys.write_log( 'Fleets' , 'TRACE'::log_level , 'About to perform outer space redirect; '
PERFORM sys.write_sql_log( 'Fleets' , 'TRACE'::log_level , 'About to perform outer space redirect; '
|| 'OOFT/2 = ' || rec.flight_time || '; start(x;y)= (' || rec.os_start_x || ';' || rec.os_start_y
|| '); dest(x;y)= (' || rec.x || ';' || rec.y || '); time left: ' || rec.mv_state_time );
SELECT INTO cx , cy c_x , c_y FROM fleets.compute_current_location(
rec.flight_time , rec.os_start_x , rec.os_start_y , rec.x , rec.y ,
rec.mv_state_time );
PERFORM sys.write_log( 'Fleets' , 'TRACE'::log_level , 'Computed current coordinates: (' || cx
PERFORM sys.write_sql_log( 'Fleets' , 'TRACE'::log_level , 'Computed current coordinates: (' || cx
|| ';' || cy || ')' );
SELECT INTO dur , s_dur duration , s_duration
FROM fleets.compute_outerspace_redirect( rec.flight_time , cx , cy , dest_id );
PERFORM sys.write_log( 'Fleets' , 'TRACE'::log_level , 'Computed new total/state duration: '
PERFORM sys.write_sql_log( 'Fleets' , 'TRACE'::log_level , 'Computed new total/state duration: '
|| dur || ' / ' || s_dur );
UPDATE fleets.ms_space SET start_x = cx , start_y = cy
WHERE movement_id = rec.id;
@ -1000,7 +1000,7 @@ DECLARE
found INT;
deleted INT;
BEGIN
PERFORM sys.write_log( 'BattleUpdate' , 'TRACE'::log_level , 'Inflicting '
PERFORM sys.write_sql_log( 'BattleUpdate' , 'TRACE'::log_level , 'Inflicting '
|| dmg || ' damage to fleet #' || f_id );
-- Get total fleet power and battle protagonist
@ -1094,7 +1094,7 @@ DECLARE
BEGIN
tick := sys.get_tick( ) - 1;
tot_damage := t_upkeep * d_ratio / debt;
PERFORM sys.write_log( 'EmpireDebt' , 'DEBUG'::log_level , 'Inflicting debt damage to fleets; total upkeep: '
PERFORM sys.write_sql_log( 'EmpireDebt' , 'DEBUG'::log_level , 'Inflicting debt damage to fleets; total upkeep: '
|| t_upkeep || ', damage ratio: ' || d_ratio || ', total damage: ' || tot_damage );
FOR f_rec IN SELECT f.id AS fleet , f.status , f.location_id AS location ,

View file

@ -585,13 +585,13 @@ BEGIN
-- Send message (or not)
IF do_send
THEN
PERFORM sys.write_log( 'Messages' , 'DEBUG'::log_level , 'Delivering message from empire #' || e_id
PERFORM sys.write_sql_log( 'Messages' , 'DEBUG'::log_level , 'Delivering message from empire #' || e_id
|| ' using method ' || s_meth || ' with target identifier ' || tg_id || ' (title text null? '
|| ( ttl_txt IS NULL ) || ' ; content text null? ' || (cnt_txt IS NULL) || ')' );
EXECUTE 'SELECT msgs.deliver_' || s_meth || '( $1 , $2 , $3 , $4 )'
USING e_id , tg_id , ttl_txt , cnt_txt;
ELSE
PERFORM sys.write_log( 'Messages' , 'DEBUG'::log_level , 'Simulated message delivery from empire #' || e_id
PERFORM sys.write_sql_log( 'Messages' , 'DEBUG'::log_level , 'Simulated message delivery from empire #' || e_id
|| ' using method ' || s_meth || ' with target identifier ' || tg_id || ' (title text null? '
|| ( ttl_txt IS NULL ) || ' ; content text null? ' || (cnt_txt IS NULL) || ')' );
END IF;
@ -860,13 +860,13 @@ BEGIN
-- Send message (or not)
IF do_send
THEN
PERFORM sys.write_log( 'Messages' , 'DEBUG'::log_level , 'Delivering message from admin #' || a_id
PERFORM sys.write_sql_log( 'Messages' , 'DEBUG'::log_level , 'Delivering message from admin #' || a_id
|| ' using method ' || s_meth || ' with target identifier ' || tg_id || ' (title text null? '
|| ( ttl_txt IS NULL ) || ' ; content text null? ' || (cnt_txt IS NULL) || ')' );
EXECUTE 'SELECT msgs.deliver_admin_' || s_meth || '( $1 , $2 , $3 , $4 )'
USING a_id , tg_id , ttl_txt , cnt_txt;
ELSE
PERFORM sys.write_log( 'Messages' , 'DEBUG'::log_level , 'Simulated message delivery from admin #' || a_id
PERFORM sys.write_sql_log( 'Messages' , 'DEBUG'::log_level , 'Simulated message delivery from admin #' || a_id
|| ' using method ' || s_meth || ' with target identifier ' || tg_id || ' (title text null? '
|| ( ttl_txt IS NULL ) || ' ; content text null? ' || (cnt_txt IS NULL) || ')' );
END IF;

View file

@ -663,7 +663,7 @@ BEGIN
INSERT INTO admin.archived_ban_requests ( request_id , credentials_id )
VALUES ( b_id , u_id );
DELETE FROM admin.active_ban_requests WHERE request_id = b_id;
PERFORM sys.write_log( 'Bans' , 'INFO'::log_level , 'Ban request #' || b_id
PERFORM sys.write_sql_log( 'Bans' , 'INFO'::log_level , 'Ban request #' || b_id
|| ' (user account #' || u_id || ') expired' );
END LOOP;
END;
@ -707,7 +707,7 @@ BEGIN
-- Delete empire and active account record
PERFORM emp.delete_empire( e_id );
DELETE FROM users.active_accounts WHERE credentials_id = a_id;
PERFORM sys.write_log( 'Bans' , 'INFO'::log_level , 'Deleted empire #' || e_id
PERFORM sys.write_sql_log( 'Bans' , 'INFO'::log_level , 'Deleted empire #' || e_id
|| ' (user account #' || a_id || ')' );
RETURN TRUE;

File diff suppressed because it is too large Load diff

View file

@ -0,0 +1,39 @@
BEGIN;
SELECT plan( 3 );
--
-- Insertion through sys.write_log()
--
CREATE OR REPLACE FUNCTION _test_this( )
RETURNS BIGINT
AS $$
SELECT sys.write_log( 'test' , 'WARNING'::log_level , 'test' );
$$ LANGUAGE SQL;
SELECT lives_ok( 'SELECT _test_this()' );
DROP FUNCTION _test_this( );
--
-- Direct insertion must fail
--
CREATE FUNCTION _test_this( )
RETURNS VOID
AS $$
INSERT INTO sys.logs( component , level , message )
VALUES ( 'test' , 'WARNING'::log_level , 'test' );
$$ LANGUAGE SQL;
SELECT throws_ok( 'SELECT _test_this()' , 42501 );
DROP FUNCTION _test_this( );
--
-- Updates must fail
--
CREATE OR REPLACE FUNCTION _test_this( )
RETURNS VOID
AS $$
UPDATE sys.logs SET component = 'random' WHERE component = 'test';
$$ LANGUAGE SQL;
SELECT throws_ok( 'SELECT _test_this()' , 42501 );
DROP FUNCTION _test_this( );
SELECT * FROM finish( );
ROLLBACK;