>Is there a way to be notified on the CREATE TABLE execution?
CREATE OR REPLACE FUNCTION public.fn_notify_ddl()
RETURNS event_trigger AS
$BODY$
DECLARE
obj record;
BEGIN
/*
RAISE INFO 'Type: %', TG_TAG;
RAISE INFO 'Command: %', current_query();
RAISE INFO 'DB Name: %', current_database();
RAISE INFO 'DB User: %', session_user;
RAISE INFO 'DB Port: %', inet_server_port();
RAISE INFO 'Server Host: %', inet_server_addr();
RAISE INFO 'Client Host: %', inet_client_addr();
*/
FOR obj IN SELECT *
FROM pg_event_trigger_ddl_commands() LOOP
IF obj.command_tag = 'CREATE TABLE'
OR obj.command_tag = 'DROP TABLE'THEN
-- RAISE INFO 'we got a % event for object "%"', obj.command_tag, obj.object_identity;
INSERT INTO tbl_create_log
( log_table_schema,
log_table_name,
log_session_user
)
SELECT n.nspname,
c.relname,
session_user
FROM pg_class c
JOIN pg_namespace n ON n.oid = c.relnamespace
WHERE c.oid = obj.objid
AND c.relkind = 'r';
END IF;
END LOOP;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
ALTER FUNCTION public.fn_notify_ddl()
OWNER TO postgres;
Here is sample code that will notify for a CREATE or DROP table:
CREATE TABLE public.tbl_create_log
(
tbl_cl_key bigint NOT NULL DEFAULT nextval('tbl_create_log_tbl_cl_key_seq'::regclass),
tbl_cre8_time timestamp without time zone DEFAULT now(),
log_table_schema name,
log_table_name name,
log_session_user name,
CONSTRAINT tbl_create_log_pk PRIMARY KEY (tbl_cl_key)
)
WITH (
OIDS=FALSE
);
ALTER TABLE public.tbl_create_log
OWNER TO postgres;
GRANT ALL ON TABLE public.tbl_create_log TO postgres;
(
tbl_cl_key bigint NOT NULL DEFAULT nextval('tbl_create_log_tbl_cl_key_seq'::regclass),
tbl_cre8_time timestamp without time zone DEFAULT now(),
log_table_schema name,
log_table_name name,
log_session_user name,
CONSTRAINT tbl_create_log_pk PRIMARY KEY (tbl_cl_key)
)
WITH (
OIDS=FALSE
);
ALTER TABLE public.tbl_create_log
OWNER TO postgres;
GRANT ALL ON TABLE public.tbl_create_log TO postgres;
CREATE OR REPLACE FUNCTION public.fn_notify_ddl()
RETURNS event_trigger AS
$BODY$
DECLARE
obj record;
BEGIN
/*
RAISE INFO 'Type: %', TG_TAG;
RAISE INFO 'Command: %', current_query();
RAISE INFO 'DB Name: %', current_database();
RAISE INFO 'DB User: %', session_user;
RAISE INFO 'DB Port: %', inet_server_port();
RAISE INFO 'Server Host: %', inet_server_addr();
RAISE INFO 'Client Host: %', inet_client_addr();
*/
FOR obj IN SELECT *
FROM pg_event_trigger_ddl_commands() LOOP
IF obj.command_tag = 'CREATE TABLE'
OR obj.command_tag = 'DROP TABLE'THEN
-- RAISE INFO 'we got a % event for object "%"', obj.command_tag, obj.object_identity;
INSERT INTO tbl_create_log
( log_table_schema,
log_table_name,
log_session_user
)
SELECT n.nspname,
c.relname,
session_user
FROM pg_class c
JOIN pg_namespace n ON n.oid = c.relnamespace
WHERE c.oid = obj.objid
AND c.relkind = 'r';
END IF;
END LOOP;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
ALTER FUNCTION public.fn_notify_ddl()
OWNER TO postgres;
CREATE EVENT TRIGGER table_created_dropped ON DDL_COMMAND_END
EXECUTE PROCEDURE public.fn_notify_ddl();
ALTER EVENT TRIGGER table_created_dropped
OWNER TO postgres;
--
EXECUTE PROCEDURE public.fn_notify_ddl();
ALTER EVENT TRIGGER table_created_dropped
OWNER TO postgres;
--
Melvin Davidson
Maj. Database & Exploration Specialist
Universe Exploration Command – UXC
Employment by invitation only!
Maj. Database & Exploration Specialist
Universe Exploration Command – UXC
Employment by invitation only!