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

2
.gitignore vendored
View file

@ -2,3 +2,5 @@ target
.settings
.classpath
.project
legacyworlds-server-main/data-source.xml
legacyworlds-server-data/db-structure/db-config.txt

55
build/post-build.sh Executable file
View file

@ -0,0 +1,55 @@
#!/bin/bash
cd legacyworlds-server-data/db-structure
if ! [ -f db-config.txt ]; then
cat > db-config.txt <<EOF
admin=$USER
db=tests
user=tests
password=tests
EOF
fi
TEST_DATABASE="`grep ^db= db-config.txt | sed -e s/.*=//`"
TEST_USER="`grep ^user= db-config.txt | sed -e s/.*=//`"
echo
echo
echo "======================================================================"
echo "LOADING DATABASE DEFINITION ..."
echo "======================================================================"
echo
echo
psql -vQUIET=1 -vON_ERROR_STOP=1 -e --file database.sql || exit 1
if ! [ -d tests/admin ] && ! [ -d tests/user ]; then
echo
echo
echo "WARNING: no unit tests to run"
echo
echo
exit 0
fi
echo
echo
echo "======================================================================"
echo "LOADING TEST FRAMEWORK ..."
echo "======================================================================"
echo
echo
psql -vQUIET=1 -f tests/pgtap.sql $TEST_DATABASE || exit 1
echo
echo
echo "======================================================================"
echo "RUNNING DATABASE TESTS ..."
echo "======================================================================"
echo
echo
cd tests
if [ -d admin ]; then
pg_prove -d $TEST_DATABASE `find admin/ -type f -name '*.sql'` || exit 1
fi
if [ -d user ]; then
pg_prove -U $TEST_USER -d $TEST_DATABASE `find user/ -type f -name '*.sql'` || exit 1
fi

View file

@ -46,13 +46,9 @@
<directory>../legacyworlds-server-data/db-structure</directory>
<outputDirectory>sql</outputDirectory>
<includes>
<include>*.sql</include>
<include>*/*.sql</include>
<include>*/*/*.sql</include>
<include>**.sql</include>
<include>db-config.sample.txt</include>
</includes>
<excludes>
<exclude>*.txt</exclude>
</excludes>
</fileSet>
<!-- Default data -->
@ -71,21 +67,12 @@
<!-- Data source configuration -->
<file>
<source>../legacyworlds-server-main/data-source.xml</source>
<destName>data-source.sample.xml</destName>
<source>../legacyworlds-server-main/data-source.sample.xml</source>
<fileMode>0600</fileMode>
<outputDirectory>.</outputDirectory>
</file>
<!-- Database definition variables -->
<file>
<source>../legacyworlds-server-data/db-structure/db-config.txt</source>
<destName>db-config.sample.txt</destName>
<fileMode>0600</fileMode>
<outputDirectory>sql</outputDirectory>
</file>
</files>
</assembly>
</assembly>

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;

View file

@ -12,19 +12,14 @@ PROJECT:
SERVER & DATABASE:
! Migrate to PostgreSQL 9.1
-> add logging to some of the bigger stored procedures through an
external connection
! Add some form of database version control to allow easier updates
-> once migrated to Pg9.1, there are some interesting extensions that
may be satisfactory
-> existing options were investigated, they are unsatisfactory
* Replace all single-precision reals with double precision reals
* Add a tool to initialise the database
* I18N loader: improve text file loading (use relative paths)
* Replace current authentication information (pair of hashes) with a
@ -41,6 +36,6 @@ GENERAL:
-> that would be "everywhere"
* Write unit tests
? Check out PostgreSQL extensions to test stored procedures
* Write unit tests for new code
* Write unit tests for all new Java code
* Write unit tests for all new SQL code
? add more tests if possible

View file

@ -0,0 +1,91 @@
Database structure and development
===================================
The database used by the Legacy Worlds server can be found in the db-structure
directory of the legacyworlds-server-data package.
Database configuration
-----------------------
The configuration used by the various SQL scripts must be placed in the
db-config.txt file, at the root of the directory. This file is ignored by Git,
which allows each developer to set up her or his own copy of the database
without hassle. A sample is included in the repository in the
db-config.sample.txt file.
The configuration file contains a few fields, which are defined using a simple
"<key>=<value>" syntax (warning: there should be no spaces before or after the
'=' sign).
The following fields must be defined:
* admin - the name of the administrative user,
* db - the name of the database,
* user - the name of the user through which the server connects to the
database,
* password - the password used by the server to authenticate when accessing
the database.
Code structure
---------------
The root directory includes a "database.sql" script, which can be launched in
psql to create the database and associated user.
The parts/ sub-directory contains the various elements of the database's
definition. It contains a few scripts, which will initialise the schemas and
load other scripts from the sub-directories.
* parts/data/ contains all data structure definitions (types, tables,
indexes, constraints and some of the views).
* parts/functions/ contains all general function definitions; this includes
both functions that are called internally and functions which are called
by the server. It also includes view definitions that depend on functions.
* parts/updates/ contains all functions that implement the game's updates.
The tests/ sub-directory contains the SQL source code for the pgTAP testing
framework as well as the tests themselves. See below for more information.
Unit tests
----------
There may be up to two sub-directories in the tests/ directory. The user/
sub-directory would contain unit tests that must be executed as the standard
user, while the admin/ directory would contain tests that required
administrative permissions on the database.
In order to run the database unit tests, the following steps must be taken:
1) pg_prove must be installed. This can be achieved by running the following
command as root:
cpan TAP::Parser::SourceHandler::pgTAP
2) It must be possible to log on to the database through the local socket as
both the administrative and the standard user, without password.
3) The database itself must be loaded using the aforementioned database.sql
script.
4) The tests/pgtap.sql script must be loaded into the database as the
administrative user.
At this point, it becomes possible to launch the test suites by issuing a
command similar to:
pg_prove -d $DATABASE -U $USER `find $DIR/ -type f -name '*.sql'`
where $DATABASE is the name of the database, $USER the name of the user that
will execute the tests and $DIR being either admin or user.
Build system
-------------
The build system will attempt to create the database using the scripts. It will
stop at the first unsuccessful command. On success, it will proceed to loading
pgTAP, then run all available unit tests. A failure will cause the build to be
aborted.