#coding:utf-8 """ ID: issue-5214 ISSUE: 5214 TITLE: Add ability to track domains rename in DDL triggers DESCRIPTION: JIRA: CORE-4923 FBTEST: bugs.core_4923 NOTES: [01.12.2023] pzotov New behaviour of ISQL was introduced after implementation of PR #7868: SET AUTOTERM. Since that was implemented, ISQL handles comments (single- and multi-lined) as PART of statement that follows these comments. In other words, ISQL in 6.x does not 'swallow' comments and sends them to engine together with statement that follows. This means that such 'pair' (comment PLUS statement) can be 'unexpectedly' seen using monitor/logging features, including rdb$get_context('DDL_TRIGGER', 'SQL_TEXT'). Currently this is not considered as a bug, see note by Adriano: https://groups.google.com/g/firebird-devel/c/AM8vlA3YJws Because of this, we have (in this test) to either not use comments at all or filter them out by applying substitution which will 'know' about some special text ('comment_tag') that must be suppressed. Checked on 6.0.0.163 """ import pytest from firebird.qa import * db = db_factory() COMMENT_TAG='DONT_SHOW_IN_OUTPUT' test_script = f""" recreate table ddl_log ( id integer generated by default as identity constraint pk_ddl_log primary key using index pk_ddl_log ,who_logs varchar(50) ,evn_type varchar(50) ,obj_type varchar(50) ,obj_name varchar(50) ,old_name varchar(50) ,new_name varchar(50) ,sql_text blob sub_type text ); commit; set term ^; -- active before create domain or alter domain or drop domain create trigger ddl_log_befo active before any ddl statement as begin insert into ddl_log( who_logs ,evn_type ,obj_type ,obj_name ,old_name ,new_name ,sql_text ) values ( 'DDL trigger BEFORE ddl statement' ,rdb$get_context('DDL_TRIGGER', 'EVENT_TYPE') ,rdb$get_context('DDL_TRIGGER', 'OBJECT_TYPE') ,rdb$get_context('DDL_TRIGGER', 'OBJECT_NAME') ,rdb$get_context('DDL_TRIGGER', 'OLD_OBJECT_NAME') ,rdb$get_context('DDL_TRIGGER', 'NEW_OBJECT_NAME') ,rdb$get_context('DDL_TRIGGER', 'SQL_TEXT') ); end ^ -- active before create domain or alter domain or drop domain create trigger ddl_log_afte active after any ddl statement as begin in autonomous transaction do insert into ddl_log( who_logs ,evn_type ,obj_type ,obj_name ,old_name ,new_name ,sql_text ) values ( 'DDL trigger AFTER ddl statement' ,rdb$get_context('DDL_TRIGGER', 'EVENT_TYPE') ,rdb$get_context('DDL_TRIGGER', 'OBJECT_TYPE') ,rdb$get_context('DDL_TRIGGER', 'OBJECT_NAME') ,rdb$get_context('DDL_TRIGGER', 'OLD_OBJECT_NAME') ,rdb$get_context('DDL_TRIGGER', 'NEW_OBJECT_NAME') ,rdb$get_context('DDL_TRIGGER', 'SQL_TEXT') ); end ^ set term ;^ commit; -- {COMMENT_TAG} here TWO transactions will start: DML and DDL. Only Tx for DDL will be auto-committed: create domain dm_foo smallint not null; -- {COMMENT_TAG} For each of following DDL statements (which are executed with AUTOCOMMIT mode) two triggers fire: -- {COMMENT_TAG} "ddl_log_befo" and "ddl_log_afte". Each trigger DOES write info about DDL changing to the log table -- {COMMENT_TAG} ("ddl_log") but it does this work in the same Tx as DDL. So, new content of DDL_LOG table can not -- {COMMENT_TAG} be seen by starting DML transaction and we should do one more COMMIT before querying it (see below). alter domain dm_foo type int; alter domain dm_foo to dm_bar; alter domain dm_bar type bigint; alter domain dm_bar drop not null; drop domain dm_bar; -- NB: 1st DML transaction was started in TIL = SNAPSHOT when we did "create domain dm_foo smallint not null;", -- so it does not yet see data in ddl_log and we have to COMMIT this DML transaction: commit; set list on; set count on; select id ,who_logs ,evn_type ,obj_type ,obj_name ,old_name ,new_name ,sql_text from ddl_log where obj_type<>'TRIGGER' order by id; """ act = isql_act('db', test_script, substitutions=[ ('SQL_TEXT.*', ''), (f'-- {COMMENT_TAG}.*', '') ]) expected_stdout = """ ID 2 WHO_LOGS DDL trigger BEFORE ddl statement EVN_TYPE CREATE OBJ_TYPE DOMAIN OBJ_NAME DM_FOO OLD_NAME NEW_NAME SQL_TEXT 80:1 create domain dm_foo smallint not null ID 3 WHO_LOGS DDL trigger AFTER ddl statement EVN_TYPE CREATE OBJ_TYPE DOMAIN OBJ_NAME DM_FOO OLD_NAME NEW_NAME SQL_TEXT 80:2 create domain dm_foo smallint not null ID 4 WHO_LOGS DDL trigger BEFORE ddl statement EVN_TYPE ALTER OBJ_TYPE DOMAIN OBJ_NAME DM_FOO OLD_NAME NEW_NAME SQL_TEXT 80:3 alter domain dm_foo type int ID 5 WHO_LOGS DDL trigger AFTER ddl statement EVN_TYPE ALTER OBJ_TYPE DOMAIN OBJ_NAME DM_FOO OLD_NAME NEW_NAME SQL_TEXT 80:4 alter domain dm_foo type int ID 6 WHO_LOGS DDL trigger BEFORE ddl statement EVN_TYPE ALTER OBJ_TYPE DOMAIN OBJ_NAME DM_FOO OLD_NAME DM_FOO NEW_NAME DM_BAR SQL_TEXT 80:5 alter domain dm_foo to dm_bar ID 7 WHO_LOGS DDL trigger AFTER ddl statement EVN_TYPE ALTER OBJ_TYPE DOMAIN OBJ_NAME DM_BAR OLD_NAME DM_FOO NEW_NAME DM_BAR SQL_TEXT 80:6 alter domain dm_foo to dm_bar ID 8 WHO_LOGS DDL trigger BEFORE ddl statement EVN_TYPE ALTER OBJ_TYPE DOMAIN OBJ_NAME DM_BAR OLD_NAME NEW_NAME SQL_TEXT 80:7 alter domain dm_bar type bigint ID 9 WHO_LOGS DDL trigger AFTER ddl statement EVN_TYPE ALTER OBJ_TYPE DOMAIN OBJ_NAME DM_BAR OLD_NAME NEW_NAME SQL_TEXT 80:8 alter domain dm_bar type bigint ID 10 WHO_LOGS DDL trigger BEFORE ddl statement EVN_TYPE ALTER OBJ_TYPE DOMAIN OBJ_NAME DM_BAR OLD_NAME NEW_NAME SQL_TEXT 80:9 alter domain dm_bar drop not null ID 11 WHO_LOGS DDL trigger AFTER ddl statement EVN_TYPE ALTER OBJ_TYPE DOMAIN OBJ_NAME DM_BAR OLD_NAME NEW_NAME SQL_TEXT 80:a alter domain dm_bar drop not null ID 12 WHO_LOGS DDL trigger BEFORE ddl statement EVN_TYPE DROP OBJ_TYPE DOMAIN OBJ_NAME DM_BAR OLD_NAME NEW_NAME SQL_TEXT 80:b drop domain dm_bar ID 13 WHO_LOGS DDL trigger AFTER ddl statement EVN_TYPE DROP OBJ_TYPE DOMAIN OBJ_NAME DM_BAR OLD_NAME NEW_NAME SQL_TEXT 80:c drop domain dm_bar Records affected: 12 """ @pytest.mark.version('>=3.0') def test_1(act: Action): act.expected_stdout = expected_stdout act.execute() assert act.clean_stdout == act.clean_expected_stdout