This repository has been archived on 2024-07-18. You can view files and clone it, but cannot push or open issues or pull requests.
lwb6/legacyworlds-server/legacyworlds-server-data/db-structure/parts/functions/005-logs-functions.sql

250 lines
8 KiB
PL/PgSQL

-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Logging functions and triggers
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- LOG CLEANUP --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Remove expired entries from a log table
--
-- Parameters:
-- l_type Log table to clean up
--
CREATE OR REPLACE FUNCTION sys.clean_log_table( l_type log_type )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
expiry INT;
expiry_int INTERVAL;
BEGIN
expiry := floor( sys.get_constant( 'log.maxAge.' || lower( l_type::TEXT ) ) );
expiry_int := ( expiry || 's' )::INTERVAL;
EXECUTE 'DELETE FROM ' || l_type::TEXT || '.logs WHERE t <= $1'
USING now() - expiry_int;
END;
$$ LANGUAGE plpgsql;
--
-- Clean all log tables
--
CREATE OR REPLACE FUNCTION sys.clean_logs( )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
lt log_type;
BEGIN
FOR lt IN SELECT x FROM unnest( enum_range( NULL::log_type ) ) AS x
LOOP
PERFORM sys.clean_log_table( lt );
END LOOP;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.clean_logs( ) TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- LOG APPENDERS --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Write an user log entry
--
CREATE OR REPLACE FUNCTION users.write_log( account_id INT , lv log_level , msg TEXT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
BEGIN
INSERT INTO users.logs (credentials_id , level , message)
VALUES ( account_id , lv , msg );
END;
$$ LANGUAGE plpgsql;
--
-- Write an administrative log entry
--
CREATE OR REPLACE FUNCTION admin.write_log( adm_id INT , lv log_level , msg TEXT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
BEGIN
INSERT INTO admin.logs ( admin_id , level , message )
VALUES ( adm_id , lv , msg );
END;
$$ LANGUAGE plpgsql;
--
-- Write a system log entry
--
CREATE OR REPLACE FUNCTION sys.write_log( cmp TEXT , lv log_level , msg TEXT , OUT entry_id BIGINT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
INSERT INTO sys.logs( component , level , message )
VALUES ( cmp , lv , msg )
RETURNING id INTO entry_id;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.write_log( TEXT , log_level , TEXT ) TO :dbuser;
--
-- Append an exception log entry
--
CREATE OR REPLACE FUNCTION sys.append_exception( l_id BIGINT , cname TEXT , msg TEXT , OUT entry_id BIGINT )
CALLED ON NULL INPUT
VOLATILE
SECURITY DEFINER
AS $$
DECLARE
d INT;
BEGIN
SELECT INTO d max( depth ) FROM sys.exceptions
WHERE log_id = l_id;
IF d IS NULL THEN
d := 0;
END IF;
d := d + 1;
INSERT INTO sys.exceptions ( log_id , depth , exc_class , message )
VALUES ( l_id , d , cname , msg )
RETURNING id INTO entry_id;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.append_exception( BIGINT , TEXT , TEXT ) TO :dbuser;
--
-- Append a stack trace entry
--
CREATE OR REPLACE FUNCTION sys.append_trace( e_id BIGINT , loc TEXT , f_name TEXT , lnb INT )
RETURNS VOID
CALLED ON NULL INPUT
VOLATILE
SECURITY DEFINER
AS $$
DECLARE
d INT;
BEGIN
SELECT INTO d max( depth ) FROM sys.stack_traces
WHERE exception_id = e_id;
IF d IS NULL THEN
d := 0;
END IF;
d := d + 1;
INSERT INTO sys.stack_traces ( exception_id , depth , location , file_name , line_number )
VALUES ( e_id , d , loc , f_name , lnb );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.append_trace( BIGINT , TEXT , TEXT , INT ) TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- LOGS VIEW FOR EASY SELECTION --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
CREATE VIEW sys.system_logs_view
AS SELECT l.id , l.t , l.component , l.level , l.message ,
( CASE WHEN e.id IS NOT NULL THEN l.id ELSE NULL END )::BIGINT AS exception_id
FROM sys.logs l
LEFT OUTER JOIN sys.exceptions e ON e.log_id = l.id AND e.depth = 1;
GRANT SELECT ON sys.system_logs_view TO :dbuser;
CREATE VIEW sys.admin_logs_view
AS SELECT NULL::BIGINT AS id , l.t , a.appear_as AS component , l.level ,
l.message , NULL::BIGINT AS exception_id
FROM admin.logs l
INNER JOIN admin.administrators a ON a.id = l.admin_id;
GRANT SELECT ON sys.admin_logs_view TO :dbuser;
CREATE VIEW sys.player_logs_view
AS SELECT NULL::BIGINT AS id , l.t , a.address AS component , l.level ,
l.message , NULL::BIGINT AS exception_id
FROM users.logs l
INNER JOIN users.addresses a ON a.id = l.credentials_id;
GRANT SELECT ON sys.player_logs_view TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- ADMIN ERROR REPORT FUNCTION --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
CREATE OR REPLACE FUNCTION admin.get_error_entries( )
RETURNS SETOF BIGINT
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
last_report TIMESTAMP WITHOUT TIME ZONE;
new_report TIMESTAMP WITHOUT TIME ZONE;
e_id BIGINT;
BEGIN
new_report := now( );
SELECT INTO last_report last_error_recap FROM sys.status FOR UPDATE;
UPDATE sys.status SET last_error_recap = new_report;
RETURN QUERY SELECT id FROM sys.system_logs_view
WHERE t >= last_report AND t < new_report AND exception_id IS NOT NULL
ORDER BY t DESC;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION admin.get_error_entries( ) TO :dbuser;