Emmanuel BENOîT
d246f221f0
Added tables that store event access interfaces and event states per interface, as well as functions which allow events to be retrieved: * events.interfaces lists access interfaces, * events.unprocessed_events lists events which haven't been processed for each type of interface, with a "pre-processed" flag * events.ep_read() is a set of function variants which will read events * events.ep_access() is a set of function variants which read events then update their states.
724 lines
19 KiB
PL/PgSQL
724 lines
19 KiB
PL/PgSQL
-- LegacyWorlds Beta 6
|
|
-- PostgreSQL database scripts
|
|
--
|
|
-- Functions that read event data and update event
|
|
-- states on behalf of event viewing / processing
|
|
-- interfaces.
|
|
--
|
|
-- Copyright(C) 2004-2012, DeepClone Development
|
|
-- --------------------------------------------------------
|
|
|
|
|
|
/*
|
|
* SOME GENERAL DOCUMENTATION
|
|
* --------------------------
|
|
*
|
|
* This file provides a few functions the server can use to access the events:
|
|
*
|
|
* The events.ep_read() function variants provide read-only access to the
|
|
* list. They may be used with or without a target (whether that target is an
|
|
* user or an empire), and they can be given an offset and a limit if partial
|
|
* selection is desired. ep_read() accepts the following parameters ("+"
|
|
* means that the parameter is required).
|
|
*
|
|
* + access interface identifier
|
|
* target identifier
|
|
* target is empire?
|
|
* + access processed events?
|
|
* + access preprocessed events?
|
|
* + access new events?
|
|
* offset of first event
|
|
* maximal amount of events
|
|
*
|
|
* The events.ep_access() function variants provide the same service, but will
|
|
* additionally update the events' state after reading them. ep_access()
|
|
* uses the same parameters as ep_read(), but adds two new mandatory parameters
|
|
* at the end:
|
|
*
|
|
* + mark preprocessed events as processed?
|
|
* + state to set for new events
|
|
*/
|
|
|
|
|
|
|
|
/*
|
|
* Insert new events in unprocessed list
|
|
* -------------------------------------
|
|
*
|
|
* This trigger function is used to insert new events into the list of
|
|
* unprocessed events for all interface types.
|
|
*/
|
|
DROP FUNCTION IF EXISTS events.tgf_insert_unprocessed( ) CASCADE;
|
|
CREATE FUNCTION events.tgf_insert_unprocessed( )
|
|
RETURNS TRIGGER
|
|
LANGUAGE PLPGSQL
|
|
STRICT VOLATILE SECURITY DEFINER
|
|
AS $tgf_insert_unprocessed$
|
|
BEGIN
|
|
INSERT INTO events.unprocessed_events( event_id , evi_id )
|
|
SELECT NEW.event_id , evi_id
|
|
FROM events.interfaces;
|
|
RETURN NEW;
|
|
END;
|
|
$tgf_insert_unprocessed$;
|
|
|
|
REVOKE EXECUTE
|
|
ON FUNCTION events.tgf_insert_unprocessed( )
|
|
FROM PUBLIC;
|
|
|
|
CREATE TRIGGER tg_insert_unprocessed
|
|
AFTER INSERT ON events.events_v2
|
|
FOR EACH ROW EXECUTE PROCEDURE events.tgf_insert_unprocessed( );
|
|
|
|
|
|
/*
|
|
* Event processing states
|
|
* -----------------------
|
|
*
|
|
* This type serves as an indication of event processing state.
|
|
*
|
|
* Note: this type is not used for storage, only for access.
|
|
*/
|
|
DROP TYPE IF EXISTS events.processing_state CASCADE;
|
|
CREATE TYPE events.processing_state AS ENUM(
|
|
/* The event is new and hasn't been processed yet */
|
|
'NEW' ,
|
|
|
|
/* The event has been preprocessed */
|
|
'PRE' ,
|
|
|
|
/* The event has been fully processed */
|
|
'DONE'
|
|
);
|
|
|
|
|
|
/*
|
|
* Event list entry
|
|
* ----------------
|
|
*
|
|
* This type corresponds to entries of the event lists returned by
|
|
* events.ep_list_events().
|
|
*/
|
|
DROP TYPE IF EXISTS events.ep_list_entry CASCADE;
|
|
CREATE TYPE events.ep_list_entry AS (
|
|
/* The event's identifier */
|
|
event_id BIGINT ,
|
|
|
|
/* The event type */
|
|
evdef_id TEXT ,
|
|
|
|
/* The user's identifier */
|
|
empire_id INT ,
|
|
|
|
/* The event's processing state */
|
|
event_state events.processing_state
|
|
);
|
|
|
|
|
|
/*
|
|
* Build the events listing query
|
|
* ------------------------------
|
|
*
|
|
* /!\ INTERNAL FUNCTION /!\
|
|
*
|
|
* This procedure generates the query string used to extract events for a given
|
|
* set of parameters.
|
|
*
|
|
* Parameters:
|
|
* _check_emp TRUE if the query ought to check the events' target
|
|
* empire, FALSE if all empires should be returned
|
|
* _accept_old Whether processed events should be selected
|
|
* _accept_pre Whether preprocessed events should be selected
|
|
* _accept_new Whether unprocessed events should be selected
|
|
*
|
|
* Returns:
|
|
* ??? The query string
|
|
*/
|
|
DROP FUNCTION IF EXISTS events.ep_make_list_query(
|
|
BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN );
|
|
CREATE FUNCTION events.ep_make_list_query(
|
|
_check_emp BOOLEAN ,
|
|
_accept_old BOOLEAN ,
|
|
_accept_pre BOOLEAN ,
|
|
_accept_new BOOLEAN )
|
|
RETURNS TEXT
|
|
LANGUAGE PLPGSQL
|
|
STRICT IMMUTABLE SECURITY INVOKER
|
|
AS $ep_make_list_query$
|
|
|
|
DECLARE
|
|
_qstr TEXT;
|
|
_wstr TEXT;
|
|
_need_or BOOLEAN;
|
|
|
|
BEGIN
|
|
IF NOT ( _accept_old OR _accept_pre OR _accept_new )
|
|
THEN
|
|
RAISE EXCEPTION 'No events accepted';
|
|
END IF;
|
|
|
|
_qstr := $sel_query$
|
|
SELECT _evt.event_id ,_evt.evdef_id , _evt.empire_id , ( CASE
|
|
WHEN _upe.upe_preprocessed IS NULL
|
|
THEN 'DONE'
|
|
WHEN _upe.upe_preprocessed
|
|
THEN 'PRE'
|
|
ELSE
|
|
'NEW'
|
|
END )::events.processing_state
|
|
FROM events.events_v2 _evt
|
|
LEFT OUTER JOIN events.unprocessed_events _upe
|
|
ON _upe.event_id = _evt.event_id AND _upe.evi_id = $1
|
|
$sel_query$;
|
|
|
|
IF _check_emp THEN
|
|
_wstr := '_evt.empire_id = $2';
|
|
ELSE
|
|
_wstr := '';
|
|
END IF;
|
|
|
|
IF NOT ( _accept_old AND _accept_pre AND _accept_new )
|
|
THEN
|
|
IF _wstr <> ''
|
|
THEN
|
|
_wstr := _wstr || ' AND ';
|
|
END IF;
|
|
_wstr := _wstr || '(';
|
|
|
|
_need_or := FALSE;
|
|
IF _accept_old THEN
|
|
_wstr := _wstr || '_upe.event_id IS NULL';
|
|
_need_or := TRUE;
|
|
END IF;
|
|
|
|
IF _accept_pre THEN
|
|
IF _need_or THEN
|
|
_wstr := _wstr || ' OR ';
|
|
ELSE
|
|
_need_or := TRUE;
|
|
END IF;
|
|
_wstr := _wstr || '_upe.upe_preprocessed';
|
|
END IF;
|
|
|
|
IF _accept_new THEN
|
|
IF _need_or THEN
|
|
_wstr := _wstr || ' OR ';
|
|
END IF;
|
|
_wstr := _wstr || 'NOT _upe.upe_preprocessed';
|
|
END IF;
|
|
|
|
_wstr := _wstr || ')';
|
|
END IF;
|
|
|
|
IF _wstr <> ''
|
|
THEN
|
|
_qstr := _qstr || ' WHERE ' || _wstr;
|
|
END IF;
|
|
|
|
_qstr := _qstr || ' ORDER BY _evt.event_id DESC';
|
|
RETURN _qstr;
|
|
END;
|
|
$ep_make_list_query$;
|
|
|
|
REVOKE EXECUTE
|
|
ON FUNCTION events.ep_make_list_query(
|
|
BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN )
|
|
FROM PUBLIC;
|
|
|
|
|
|
|
|
/*
|
|
* List events
|
|
* -----------
|
|
*
|
|
* /!\ INTERNAL FUNCTION /!\
|
|
*
|
|
* This procedure generates a list of events for some type of interface.
|
|
*
|
|
* Parameters:
|
|
* _evi_id Identifier of the interface accessing events
|
|
* _empire_id The identifier of the empire to get events for (may be NULL)
|
|
* _accept_old Whether processed events should be selected
|
|
* _accept_pre Whether preprocessed events should be selected
|
|
* _accept_new Whether unprocessed events should be selected
|
|
*
|
|
* Returns:
|
|
* the set of events
|
|
*/
|
|
DROP FUNCTION IF EXISTS events.ep_list_events(
|
|
TEXT , INT , BOOLEAN , BOOLEAN , BOOLEAN );
|
|
CREATE FUNCTION events.ep_list_events(
|
|
_evi_id TEXT ,
|
|
_empire_id INT ,
|
|
_accept_old BOOLEAN ,
|
|
_accept_pre BOOLEAN ,
|
|
_accept_new BOOLEAN )
|
|
RETURNS SETOF events.ep_list_entry
|
|
LANGUAGE PLPGSQL
|
|
CALLED ON NULL INPUT
|
|
STABLE SECURITY INVOKER
|
|
AS $ep_list_events$
|
|
|
|
DECLARE
|
|
_record events.ep_list_entry;
|
|
|
|
BEGIN
|
|
FOR _record IN EXECUTE events.ep_make_list_query(
|
|
_empire_id IS NOT NULL ,
|
|
_accept_old , _accept_pre , _accept_new )
|
|
USING _evi_id , _empire_id
|
|
LOOP
|
|
RETURN NEXT _record;
|
|
END LOOP;
|
|
END;
|
|
$ep_list_events$;
|
|
|
|
REVOKE EXECUTE
|
|
ON FUNCTION events.ep_list_events(
|
|
TEXT , INT , BOOLEAN , BOOLEAN , BOOLEAN )
|
|
FROM PUBLIC;
|
|
|
|
|
|
|
|
DROP TYPE IF EXISTS events.event_list_type CASCADE;
|
|
CREATE TYPE events.event_list_type AS (
|
|
/* Identifier of the empire to which the event applies */
|
|
empire_id INT ,
|
|
|
|
/* Identifier of the user who controls the empire */
|
|
user_id INT ,
|
|
|
|
/* Selected language for the empire */
|
|
lang_id TEXT ,
|
|
|
|
/* Numeric identifier of the event */
|
|
event_id BIGINT ,
|
|
|
|
/* The event's processing state */
|
|
event_state events.processing_state ,
|
|
|
|
/* Real time at which the event occurred */
|
|
event_rtime TIMESTAMP WITHOUT TIME ZONE ,
|
|
|
|
/* Game time (tick identifier) at which the event occurred */
|
|
event_gtime BIGINT ,
|
|
|
|
/* Event priority from either the definition or the custom priorities */
|
|
event_priority INT ,
|
|
|
|
/* Type of the event */
|
|
evdef_id TEXT ,
|
|
|
|
/* Internationalised string that contains the name of the event type;
|
|
* used when displaying priority settings.
|
|
*/
|
|
evdef_name TEXT ,
|
|
|
|
/* Internationalised string that contains the template to use when
|
|
* generating the output for a single event.
|
|
*/
|
|
evdef_template TEXT ,
|
|
|
|
/* Field name */
|
|
efdef_id TEXT ,
|
|
|
|
/* Field value */
|
|
field_value TEXT
|
|
);
|
|
|
|
|
|
|
|
/*
|
|
* Main events listing function
|
|
* ----------------------------
|
|
*
|
|
* /!\ INTERNAL FUNCTION /!\
|
|
*
|
|
* This function contains the main code for event access. It is capable of
|
|
* selecting events based on their target and/or state, can limit the amount
|
|
* of events fetched or fetch them starting from some offset, and is capable
|
|
* of updating event states for selected events.
|
|
*
|
|
* Parameters:
|
|
* _evi_id The identifier of the interface accessing the events list
|
|
* _target_id An empire or user identifier (may be NULL)
|
|
* _target_is_emp Whether the specified identifier is an empire (TRUE) or an
|
|
* user. May be NULL.
|
|
* _accept_old Whether processed events should be selected
|
|
* _accept_pre Whether preprocessed events should be selected
|
|
* _accept_new Whether unprocessed events should be selected
|
|
* _offset Offset of the first event to obtain in the list. May be
|
|
* NULL.
|
|
* _limit Maximal amount of events to list. May be NULL.
|
|
* _clear_pre If TRUE, selected events that had been preprocessed will
|
|
* be marked as fully processed. May be NULL.
|
|
* _change_new The state to which new events should be set. May be NULL
|
|
* or 'NEW' if no changes are to be made.
|
|
*
|
|
* Returns:
|
|
* A set of events.event_list_type records
|
|
*/
|
|
DROP FUNCTION IF EXISTS events.ep_get_events_internal(
|
|
TEXT , INT , BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN , INT , INT , BOOLEAN ,
|
|
events.processing_state ) CASCADE;
|
|
CREATE FUNCTION events.ep_get_events_internal(
|
|
_evi_id TEXT ,
|
|
_target_id INT ,
|
|
_target_is_emp BOOLEAN ,
|
|
_accept_old BOOLEAN ,
|
|
_accept_pre BOOLEAN ,
|
|
_accept_new BOOLEAN ,
|
|
_offset INT ,
|
|
_limit INT ,
|
|
_clear_pre BOOLEAN ,
|
|
_change_new events.processing_state )
|
|
RETURNS SETOF events.event_list_type
|
|
LANGUAGE PLPGSQL
|
|
CALLED ON NULL INPUT
|
|
VOLATILE SECURITY INVOKER
|
|
AS $ep_get_events_internal$
|
|
|
|
DECLARE
|
|
_sel_query TEXT;
|
|
_empire_id INT;
|
|
_record events.event_list_type;
|
|
|
|
BEGIN
|
|
-- Get empire identifier if necessary
|
|
IF NOT _target_is_emp
|
|
THEN
|
|
SELECT INTO _empire_id _emp.name_id
|
|
FROM emp.empires _emp
|
|
INNER JOIN naming.empire_names _emp_name
|
|
ON _emp.name_id = _emp_name.id
|
|
WHERE _emp_name.owner_id = _target_id;
|
|
IF NOT FOUND
|
|
THEN
|
|
RETURN;
|
|
END IF;
|
|
ELSE
|
|
_empire_id := _target_id;
|
|
END IF;
|
|
|
|
-- Generate event selection query
|
|
_sel_query := $sel_query$
|
|
CREATE TEMPORARY TABLE ep_selected
|
|
ON COMMIT DROP
|
|
AS SELECT * FROM events.ep_list_events(
|
|
$1 , $2 , $3 , $4 , $5 )
|
|
$sel_query$;
|
|
IF _offset >= 0
|
|
THEN
|
|
_sel_query := _sel_query || ' OFFSET ' || _offset;
|
|
END IF;
|
|
IF _limit > 0
|
|
THEN
|
|
_sel_query := _sel_query || ' LIMIT ' || _limit;
|
|
END IF;
|
|
|
|
-- Select events
|
|
EXECUTE _sel_query
|
|
USING _evi_id , _empire_id , _accept_old , _accept_pre , _accept_new;
|
|
|
|
-- Update event states if necessary
|
|
IF _clear_pre THEN
|
|
DELETE FROM events.unprocessed_events
|
|
WHERE event_id IN ( SELECT event_id FROM ep_selected )
|
|
AND upe_preprocessed
|
|
AND evi_id = _evi_id;
|
|
END IF;
|
|
IF _change_new = 'DONE'
|
|
THEN
|
|
DELETE FROM events.unprocessed_events
|
|
WHERE event_id IN ( SELECT event_id FROM ep_selected )
|
|
AND NOT upe_preprocessed
|
|
AND evi_id = _evi_id;
|
|
ELSIF _change_new = 'PRE'
|
|
THEN
|
|
UPDATE events.unprocessed_events _upe
|
|
SET upe_preprocessed = TRUE
|
|
FROM ep_selected _sel
|
|
WHERE _sel.event_id = _upe.event_id
|
|
AND NOT _upe.upe_preprocessed
|
|
AND _upe.evi_id = _evi_id;
|
|
END IF;
|
|
|
|
-- Select and return event data
|
|
FOR _record IN
|
|
SELECT _sel.empire_id , _emp_name.owner_id AS user_id ,
|
|
_lg.language AS lang_id , _sel.event_id ,
|
|
_sel.event_state , _ev.event_rtime , _ev.event_gtime ,
|
|
( CASE
|
|
WHEN _cp.evcp_priority IS NULL
|
|
THEN _evdef.evdef_priority
|
|
ELSE
|
|
_cp.evcp_priority
|
|
END ) AS event_priority ,
|
|
_evdef.evdef_id , _edns.name AS evdef_name ,
|
|
_edts.name AS evdef_template , _fval.efdef_id ,
|
|
_fval.efval_litteral AS field_value
|
|
FROM ep_selected _sel
|
|
INNER JOIN events.events_v2 _ev
|
|
USING ( event_id , evdef_id )
|
|
INNER JOIN events.event_definitions _evdef
|
|
USING ( evdef_id )
|
|
INNER JOIN naming.empire_names _emp_name
|
|
ON _emp_name.id = _sel.empire_id
|
|
INNER JOIN users.credentials _user
|
|
ON _user.address_id = _emp_name.owner_id
|
|
INNER JOIN defs.languages _lg
|
|
ON _lg.id = _user.language_id
|
|
INNER JOIN defs.strings _edns
|
|
ON _edns.id = _evdef.evdef_name_id
|
|
INNER JOIN defs.strings _edts
|
|
ON _edts.id = _evdef.evdef_template_id
|
|
LEFT OUTER JOIN events.field_values _fval
|
|
USING ( event_id , evdef_id )
|
|
LEFT OUTER JOIN events.custom_priorities _cp
|
|
USING ( evdef_id , evdef_adjustable , address_id )
|
|
LOOP
|
|
RETURN NEXT _record;
|
|
END LOOP;
|
|
|
|
DROP TABLE ep_selected;
|
|
END;
|
|
$ep_get_events_internal$;
|
|
|
|
REVOKE EXECUTE
|
|
ON FUNCTION events.ep_get_events_internal(
|
|
TEXT , INT , BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN , INT , INT ,
|
|
BOOLEAN , events.processing_state )
|
|
FROM PUBLIC;
|
|
|
|
|
|
|
|
/*
|
|
* READ-ONLY EVENT ACCESS WRAPPERS
|
|
*/
|
|
DROP FUNCTION IF EXISTS events.ep_read( TEXT, BOOLEAN , BOOLEAN , BOOLEAN );
|
|
CREATE FUNCTION events.ep_read(
|
|
_evi_id TEXT ,
|
|
_accept_old BOOLEAN ,
|
|
_accept_pre BOOLEAN ,
|
|
_accept_new BOOLEAN )
|
|
RETURNS SETOF events.event_list_type
|
|
LANGUAGE SQL
|
|
STRICT VOLATILE SECURITY DEFINER
|
|
AS $ep_read$
|
|
SELECT * FROM events.ep_get_events_internal( $1 , NULL , NULL , $2 , $3 ,
|
|
$4 , NULL , NULL , NULL , NULL );
|
|
$ep_read$;
|
|
|
|
REVOKE EXECUTE
|
|
ON FUNCTION events.ep_read( TEXT , BOOLEAN , BOOLEAN , BOOLEAN )
|
|
FROM PUBLIC;
|
|
GRANT EXECUTE
|
|
ON FUNCTION events.ep_read( TEXT , BOOLEAN , BOOLEAN , BOOLEAN )
|
|
TO :dbuser;
|
|
|
|
DROP FUNCTION IF EXISTS events.ep_read(
|
|
TEXT , INT , BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN );
|
|
CREATE FUNCTION events.ep_read(
|
|
_evi_id TEXT ,
|
|
_target_id INT ,
|
|
_target_is_emp BOOLEAN ,
|
|
_accept_old BOOLEAN ,
|
|
_accept_pre BOOLEAN ,
|
|
_accept_new BOOLEAN )
|
|
RETURNS SETOF events.event_list_type
|
|
LANGUAGE SQL
|
|
STRICT VOLATILE SECURITY DEFINER
|
|
AS $ep_read$
|
|
SELECT * FROM events.ep_get_events_internal( $1 , $2 , $3 , $4 , $5 , $6 ,
|
|
NULL , NULL , NULL , NULL );
|
|
$ep_read$;
|
|
|
|
REVOKE EXECUTE
|
|
ON FUNCTION events.ep_read(
|
|
TEXT , INT , BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN )
|
|
FROM PUBLIC;
|
|
GRANT EXECUTE
|
|
ON FUNCTION events.ep_read(
|
|
TEXT , INT , BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN )
|
|
TO :dbuser;
|
|
|
|
DROP FUNCTION IF EXISTS events.ep_read(
|
|
TEXT, BOOLEAN , BOOLEAN , BOOLEAN , INT , INT );
|
|
CREATE FUNCTION events.ep_read(
|
|
_evi_id TEXT ,
|
|
_accept_old BOOLEAN ,
|
|
_accept_pre BOOLEAN ,
|
|
_accept_new BOOLEAN ,
|
|
_offset INT ,
|
|
_limit INT )
|
|
RETURNS SETOF events.event_list_type
|
|
LANGUAGE SQL
|
|
STRICT VOLATILE SECURITY DEFINER
|
|
AS $ep_read$
|
|
SELECT * FROM events.ep_get_events_internal( $1 , NULL , NULL , $2 , $3 ,
|
|
$4 , $5 , $6 , NULL , NULL );
|
|
$ep_read$;
|
|
|
|
REVOKE EXECUTE
|
|
ON FUNCTION events.ep_read(
|
|
TEXT , BOOLEAN , BOOLEAN , BOOLEAN , INT , INT )
|
|
FROM PUBLIC;
|
|
GRANT EXECUTE
|
|
ON FUNCTION events.ep_read(
|
|
TEXT , BOOLEAN , BOOLEAN , BOOLEAN , INT , INT )
|
|
TO :dbuser;
|
|
|
|
DROP FUNCTION IF EXISTS events.ep_read(
|
|
TEXT , INT , BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN , INT , INT );
|
|
CREATE FUNCTION events.ep_read(
|
|
_evi_id TEXT ,
|
|
_target_id INT ,
|
|
_target_is_emp BOOLEAN ,
|
|
_accept_old BOOLEAN ,
|
|
_accept_pre BOOLEAN ,
|
|
_accept_new BOOLEAN ,
|
|
_offset INT ,
|
|
_limit INT )
|
|
RETURNS SETOF events.event_list_type
|
|
LANGUAGE SQL
|
|
STRICT VOLATILE SECURITY DEFINER
|
|
AS $ep_read$
|
|
SELECT * FROM events.ep_get_events_internal( $1 , $2 , $3 , $4 , $5 , $6 ,
|
|
$7 , $8 , NULL , NULL );
|
|
$ep_read$;
|
|
|
|
REVOKE EXECUTE
|
|
ON FUNCTION events.ep_read(
|
|
TEXT , INT , BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN , INT , INT )
|
|
FROM PUBLIC;
|
|
GRANT EXECUTE
|
|
ON FUNCTION events.ep_read(
|
|
TEXT , INT , BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN , INT , INT )
|
|
TO :dbuser;
|
|
|
|
|
|
/*
|
|
* EVENT ACCESS WRAPPERS WITH UPDATE CAPABILITIES
|
|
*/
|
|
DROP FUNCTION IF EXISTS events.ep_access(
|
|
TEXT, BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN , events.processing_state );
|
|
CREATE FUNCTION events.ep_access(
|
|
_evi_id TEXT ,
|
|
_accept_old BOOLEAN ,
|
|
_accept_pre BOOLEAN ,
|
|
_accept_new BOOLEAN ,
|
|
_clear_pre BOOLEAN ,
|
|
_change_new events.processing_state )
|
|
RETURNS SETOF events.event_list_type
|
|
LANGUAGE SQL
|
|
STRICT VOLATILE SECURITY DEFINER
|
|
AS $ep_access$
|
|
SELECT * FROM events.ep_get_events_internal( $1 , NULL , NULL , $2 , $3 ,
|
|
$4 , NULL , NULL , $5 , $6 );
|
|
$ep_access$;
|
|
|
|
REVOKE EXECUTE
|
|
ON FUNCTION events.ep_access(
|
|
TEXT , BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN ,
|
|
events.processing_state )
|
|
FROM PUBLIC;
|
|
GRANT EXECUTE
|
|
ON FUNCTION events.ep_access(
|
|
TEXT , BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN ,
|
|
events.processing_state )
|
|
TO :dbuser;
|
|
|
|
DROP FUNCTION IF EXISTS events.ep_access(
|
|
TEXT , INT , BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN ,
|
|
events.processing_state );
|
|
CREATE FUNCTION events.ep_access(
|
|
_evi_id TEXT ,
|
|
_target_id INT ,
|
|
_target_is_emp BOOLEAN ,
|
|
_accept_old BOOLEAN ,
|
|
_accept_pre BOOLEAN ,
|
|
_accept_new BOOLEAN ,
|
|
_clear_pre BOOLEAN ,
|
|
_change_new events.processing_state )
|
|
RETURNS SETOF events.event_list_type
|
|
LANGUAGE SQL
|
|
STRICT VOLATILE SECURITY DEFINER
|
|
AS $ep_access$
|
|
SELECT * FROM events.ep_get_events_internal( $1 , $2 , $3 , $4 , $5 , $6 ,
|
|
NULL , NULL , $7 , $8 );
|
|
$ep_access$;
|
|
|
|
REVOKE EXECUTE
|
|
ON FUNCTION events.ep_access(
|
|
TEXT , INT , BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN ,
|
|
BOOLEAN , events.processing_state )
|
|
FROM PUBLIC;
|
|
GRANT EXECUTE
|
|
ON FUNCTION events.ep_access(
|
|
TEXT , INT , BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN ,
|
|
BOOLEAN , events.processing_state )
|
|
TO :dbuser;
|
|
|
|
DROP FUNCTION IF EXISTS events.ep_access(
|
|
TEXT, BOOLEAN , BOOLEAN , BOOLEAN , INT , INT , BOOLEAN ,
|
|
events.processing_state );
|
|
CREATE FUNCTION events.ep_access(
|
|
_evi_id TEXT ,
|
|
_accept_old BOOLEAN ,
|
|
_accept_pre BOOLEAN ,
|
|
_accept_new BOOLEAN ,
|
|
_offset INT ,
|
|
_limit INT ,
|
|
_clear_pre BOOLEAN ,
|
|
_change_new events.processing_state )
|
|
RETURNS SETOF events.event_list_type
|
|
LANGUAGE SQL
|
|
STRICT VOLATILE SECURITY DEFINER
|
|
AS $ep_access$
|
|
SELECT * FROM events.ep_get_events_internal( $1 , NULL , NULL , $2 , $3 ,
|
|
$4 , $5 , $6 , $7 , $8 );
|
|
$ep_access$;
|
|
|
|
REVOKE EXECUTE
|
|
ON FUNCTION events.ep_access(
|
|
TEXT , BOOLEAN , BOOLEAN , BOOLEAN , INT , INT , BOOLEAN ,
|
|
events.processing_state )
|
|
FROM PUBLIC;
|
|
GRANT EXECUTE
|
|
ON FUNCTION events.ep_access(
|
|
TEXT , BOOLEAN , BOOLEAN , BOOLEAN , INT , INT , BOOLEAN ,
|
|
events.processing_state )
|
|
TO :dbuser;
|
|
|
|
DROP FUNCTION IF EXISTS events.ep_access(
|
|
TEXT , INT , BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN , INT , INT , BOOLEAN ,
|
|
events.processing_state );
|
|
CREATE FUNCTION events.ep_access(
|
|
_evi_id TEXT ,
|
|
_target_id INT ,
|
|
_target_is_emp BOOLEAN ,
|
|
_accept_old BOOLEAN ,
|
|
_accept_pre BOOLEAN ,
|
|
_accept_new BOOLEAN ,
|
|
_offset INT ,
|
|
_limit INT ,
|
|
_clear_pre BOOLEAN ,
|
|
_change_new events.processing_state )
|
|
RETURNS SETOF events.event_list_type
|
|
LANGUAGE SQL
|
|
STRICT VOLATILE SECURITY DEFINER
|
|
AS $ep_access$
|
|
SELECT * FROM events.ep_get_events_internal( $1 , $2 , $3 , $4 , $5 , $6 ,
|
|
$7 , $8 , $9 , $10 );
|
|
$ep_access$;
|
|
|
|
REVOKE EXECUTE
|
|
ON FUNCTION events.ep_access(
|
|
TEXT , INT , BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN , INT , INT,
|
|
BOOLEAN , events.processing_state )
|
|
FROM PUBLIC;
|
|
GRANT EXECUTE
|
|
ON FUNCTION events.ep_access(
|
|
TEXT , INT , BOOLEAN , BOOLEAN , BOOLEAN , BOOLEAN , INT , INT ,
|
|
BOOLEAN , events.processing_state )
|
|
TO :dbuser;
|