SQL logging fixes

* Added user mapping on the "remote" logging database for the
administrative user. This allows calls to sys.write_sql_log() to succeed
when they are executed by code with administrative privileges.

* Added test suites for both the link to the database and the function
itself.

* Replaced RAISE NOTICE with actual logging in the universe generator
This commit is contained in:
Emmanuel BENOîT 2012-01-07 11:14:17 +01:00
parent e50775ec76
commit 3e109b13bc
9 changed files with 177 additions and 64 deletions

View file

@ -14,10 +14,17 @@ CREATE EXTENSION dblink;
*/ */
CREATE FOREIGN DATA WRAPPER pgsql CREATE FOREIGN DATA WRAPPER pgsql
VALIDATOR postgresql_fdw_validator; VALIDATOR postgresql_fdw_validator;
CREATE SERVER srv_logging CREATE SERVER srv_logging
FOREIGN DATA WRAPPER pgsql FOREIGN DATA WRAPPER pgsql
OPTIONS ( hostaddr '127.0.0.1' , dbname :dbname_string ); OPTIONS ( hostaddr '127.0.0.1' , dbname :dbname_string );
CREATE USER MAPPING FOR :pgadmin
SERVER srv_logging
OPTIONS ( user :dbuser_string , password :dbupass );
CREATE USER MAPPING FOR :dbuser CREATE USER MAPPING FOR :dbuser
SERVER srv_logging SERVER srv_logging
OPTIONS ( user :dbuser_string , password :dbupass ); OPTIONS ( user :dbuser_string , password :dbupass );
GRANT USAGE ON FOREIGN SERVER srv_logging TO :dbuser; GRANT USAGE ON FOREIGN SERVER srv_logging TO :dbuser;

View file

@ -124,21 +124,21 @@ $$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.write_log( TEXT , log_level , TEXT ) TO :dbuser; GRANT EXECUTE ON FUNCTION sys.write_log( TEXT , log_level , TEXT ) TO :dbuser;
-- /*
-- Remotely append a system log entry * Remotely append a system log entry
-- *
-- This function is called from within transactions in order to write to the * This function is called from within transactions in order to write to the
-- system log. Unlike sys.write_log(), entries added through this function * system log. Unlike sys.write_log(), entries added through this function
-- will not be lost if the transaction is rolled back. * 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 * 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. * anything as the identifier of the new entry is not required.
-- *
-- Parameters: * Parameters:
-- _component The component that is appending to the log * _component The component that is appending to the log
-- _level The log level * _level The log level
-- _message The message to write * _message The message to write
-- */
CREATE OR REPLACE FUNCTION sys.write_sql_log( _component TEXT , _level log_level , _message TEXT ) CREATE OR REPLACE FUNCTION sys.write_sql_log( _component TEXT , _level log_level , _message TEXT )
RETURNS VOID RETURNS VOID
@ -146,14 +146,19 @@ CREATE OR REPLACE FUNCTION sys.write_sql_log( _component TEXT , _level log_level
SECURITY INVOKER SECURITY INVOKER
AS $write_sql_log$ AS $write_sql_log$
BEGIN BEGIN
PERFORM dblink_connect( 'cn_logging' , 'srv_logging' ); BEGIN
PERFORM dblink_connect( 'cn_logging' , 'srv_logging' );
EXCEPTION
WHEN duplicate_object THEN
-- Ignore the error, assume we're connected
END;
PERFORM * FROM dblink( 'cn_logging' , PERFORM * FROM dblink( 'cn_logging' ,
'SELECT * FROM sys.write_log( ' 'SELECT * FROM sys.write_log( '
|| quote_literal( _component ) || ' , ''' || quote_literal( _component ) || ' , '''
|| _level::text || '''::log_level , ' || _level::text || '''::log_level , '
|| quote_literal( _message ) || ' )' || quote_literal( _message ) || ' )'
) AS ( entry_id bigint ); ) AS ( entry_id bigint );
PERFORM dblink_disconnect( 'cn_logging' );
END; END;
$write_sql_log$ LANGUAGE plpgsql; $write_sql_log$ LANGUAGE plpgsql;

View file

@ -250,9 +250,10 @@ BEGIN
_recovery := verse.get_random_part( _tot_recovery , _providers_left , _recovery := verse.get_random_part( _tot_recovery , _providers_left ,
_data.recovery_avg , _data.recovery_dev ); _data.recovery_avg , _data.recovery_dev );
RAISE NOTICE 'Resource #% planet #%: quantity: % difficulty: % recovery: %', PERFORM sys.write_sql_log( 'UniverseGenerator' , 'TRACE'::log_level ,
_data.resource_name_id , _planet , 'Resource #' || _data.resource_name_id || ', planet #' || _planet
_quantity , _difficulty , _recovery; || ': quantity ' || _quantity || ' , difficulty '
|| _difficulty || ' , recovery ' || _recovery );
INSERT INTO verse.resource_providers ( INSERT INTO verse.resource_providers (
planet_id , resource_name_id , resprov_quantity_max , planet_id , resource_name_id , resprov_quantity_max ,
@ -326,11 +327,13 @@ BEGIN
_tot_recovery := verse.compute_rpp_delta( _data.providers , _create , _tot_recovery := verse.compute_rpp_delta( _data.providers , _create ,
_data.recovery , _data.recovery_avg , _data.recovery_dev ); _data.recovery , _data.recovery_avg , _data.recovery_dev );
RAISE NOTICE 'Resource #%: % new provider(s), quantity: % (avg. %) , difficulty: % (avg. %), recovery: % (avg. %)', PERFORM sys.write_sql_log( 'UniverseGenerator' , 'TRACE'::log_level ,
_data.resource_name_id , _create , 'Resource #' || _data.resource_name_id || ': ' || _create
_tot_quantity , _tot_quantity / _create , || ' new provider(s), quantity: ' || _tot_quantity || ' (avg. '
_tot_difficulty , _tot_difficulty / _create , || ( _tot_quantity / _create ) || ') , difficulty: '
_tot_recovery , _tot_recovery / _create; || _tot_difficulty || ' (avg. ' || ( _tot_difficulty / _create )
|| '), recovery: ' || _tot_recovery || ' (avg. '
|| _tot_recovery / _create || ')' );
-- Select random planets to add resource providers to -- Select random planets to add resource providers to
FOR _planet IN SELECT * FROM verse.list_random_planets_in( _area , _create ) FOR _planet IN SELECT * FROM verse.list_random_planets_in( _area , _create )

View file

@ -0,0 +1,40 @@
/*
* Test the presence and configuration of the dblink
* extension
*/
BEGIN;
SELECT plan( 6 );
SELECT diag_test_name( 'dblink - dblink_connect() exists' );
SELECT has_function( 'dblink_connect' );
SELECT diag_test_name( 'dblink - Foreign data wrapper defined' );
SELECT is( p.proname , 'postgresql_fdw_validator' )
FROM pg_foreign_data_wrapper w
INNER JOIN pg_proc p ON w.fdwvalidator = p.oid
WHERE w.fdwname = 'pgsql';
SELECT diag_test_name( 'dblink - Foreign server defined' );
SELECT is ( w.fdwname , 'pgsql' )
FROM pg_foreign_server s
INNER JOIN pg_foreign_data_wrapper w
ON s.srvfdw = w.oid
WHERE s.srvname = 'srv_logging';
SELECT diag_test_name( 'dblink - Connection' );
SELECT lives_ok(
$$ SELECT dblink_connect( 'cn_logging' , 'srv_logging' ) $$
);
SELECT diag_test_name( 'dblink - Remote user is not the administrator' );
SELECT isnt( username , current_user::TEXT )
FROM dblink( 'cn_logging' , 'SELECT current_user' )
AS ( username TEXT );
SELECT diag_test_name( 'dblink - Disconnection' );
SELECT lives_ok(
$$ SELECT dblink_disconnect( 'cn_logging' ) $$
);
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,32 @@
/*
* Test the sys.write_sql_log( ) function
*/
BEGIN;
DELETE FROM sys.logs;
SELECT plan( 4 );
SELECT diag_test_name( 'sys.write_sql_log( ) - Initial call' );
SELECT lives_ok(
$$ SELECT sys.write_sql_log( 'test' , 'WARNING'::log_level , 'test' ) $$
);
SELECT diag_test_name( 'sys.write_sql_log( ) - Contents of system log after call' );
SELECT is( COUNT(*)::INT , 1 ) FROM sys.logs;
DELETE FROM sys.logs;
SELECT diag_test_name( 'sys.write_sql_log( ) - Two calls in sequence' );
SELECT lives_ok(
$$ SELECT sys.write_sql_log( 'test' , 'WARNING'::log_level , 'test' );
SELECT sys.write_sql_log( 'test' , 'WARNING'::log_level , 'test' ) $$
);
DELETE FROM sys.logs;
SELECT diag_test_name( 'sys.write_sql_log( ) - Calling and rolling back' );
SAVEPOINT before_log;
SELECT sys.write_sql_log( 'test' , 'WARNING'::log_level , 'test' );
SELECT sys.write_log( 'test' , 'WARNING'::log_level , 'test' );
ROLLBACK TO SAVEPOINT before_log;
SELECT is( COUNT(*)::INT , 1 ) FROM sys.logs;
DELETE FROM sys.logs;
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,23 @@
/*
* Test the configuration of the dblink extension from the user's perspective
*/
BEGIN;
SELECT plan( 3 );
SELECT diag_test_name( 'dblink - Connection' );
SELECT lives_ok(
$$ SELECT dblink_connect( 'cn_logging' , 'srv_logging' ) $$
);
SELECT diag_test_name( 'dblink - Remote user = local user' );
SELECT is( username , current_user::TEXT )
FROM dblink( 'cn_logging' , 'SELECT current_user' )
AS ( username TEXT );
SELECT diag_test_name( 'dblink - Disconnection' );
SELECT lives_ok(
$$ SELECT dblink_disconnect( 'cn_logging' ) $$
);
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,29 @@
/*
* Test privileges on sys.logs
*/
BEGIN;
SELECT plan( 4 );
SELECT diag_test_name( 'sys.logs - INSERT privileges' );
SELECT throws_ok(
$$ INSERT INTO sys.logs( component , level , message )
VALUES ( 'test' , 'WARNING'::log_level , 'test' );
$$ , 42501 );
SELECT diag_test_name( 'sys.logs - UPDATE privileges' );
SELECT throws_ok(
$$ UPDATE sys.logs SET component = 'retest'; $$ ,
42501 );
SELECT diag_test_name( 'sys.logs - SELECT privileges' );
SELECT lives_ok(
$$ SELECT * FROM sys.logs; $$
);
SELECT diag_test_name( 'sys.logs - DELETE privileges' );
SELECT throws_ok(
$$ DELETE FROM sys.logs; $$ ,
42501 );
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,13 @@
/*
* Test the sys.write_sql_log( ) function
*/
BEGIN;
SELECT plan( 1 );
SELECT diag_test_name( 'sys.write_sql_log( ) - Privileges' );
SELECT lives_ok(
$$ SELECT sys.write_sql_log( 'test' , 'WARNING'::log_level , 'test' ) $$
);
SELECT * FROM finish( );
ROLLBACK;

View file

@ -1,39 +0,0 @@
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;