#coding:utf-8 """ ID: issue-4203 ISSUE: https://github.com/FirebirdSQL/firebird/issues/4203 TITLE: DROP [IF EXISTS] DESCRIPTION: Test uses pre-created databases.conf which has alias (see variable REQUIRED_ALIAS) and SecurityDatabase in its details which points to that alias, thus making such database be self-security. Database file for that alias must NOT exist in the QA_root/files/qa/ subdirectory: it will be created here. This database MUST be self-secutity because test creates GLOBAL mapping which must not be written to default security.db We create objects of all types which are enumerated in doc to be avaliable for 'DROP [IF EXISTS]' statement, and also we create DDL triggers for log appropriate activity in the table 'log_ddl_triggers_activity'. Then we run DROP IF EXISTS statements: * for existing objects (and this must be logged) * for NON-existing objects (and this must not be logged). Also, we check 'ALTER TABLE DROP COLUMN IF EXISTS' for combination of existing and non-existing columns (it must be logged). Finally, content of table 'log_ddl_triggers_activity' is checked. Every issued DDL statement must be logged FOUR times: two by before- and after-triggers for this event and two by 'universal' triggers for ANY DDL STATEMENT. NOTES: [09.01.2024] pzotov 1. One need to be sure that firebird.conf does NOT contain DatabaseAccess = None. 2. Value of REQUIRED_ALIAS must be EXACTLY the same as alias specified in the pre-created databases.conf (for LINUX this equality is case-sensitive, even when aliases are compared!) 3. Content of databases.conf must be taken from $QA_ROOT/files/qa-databases.conf (one need to replace it before every test session). Discussed with pcisar, letters since 30-may-2022 13:48, subject: "new qa, core_4964_test.py: strange outcome when use... shutil.copy() // comparing to shutil.copy2()" 4. It is crucial to be sure that current OS environment has no ISC_USER and ISC_PASSWORD variables. Test forcibly unsets them. Checked on 6.0.0.199 (after https://github.com/FirebirdSQL/firebird/commit/252a675c2adb95aca4fecb42d7433b39f669c20a). """ import os import re import locale from pathlib import Path import pytest from firebird.qa import * substitutions = [('[ \t]+', ' '), ] REQUIRED_ALIAS = 'tmp_gh_4203_alias' # MANDATORY! OTHERWISE ISC_ variables will take precedense over credentials = False! for v in ('ISC_USER','ISC_PASSWORD'): try: del os.environ[ v ] except KeyError as e: pass db = db_factory() act = python_act('db', substitutions=substitutions) @pytest.mark.version('>=6.0') def test_1(act: Action, capsys): # Scan line-by-line through databases.conf, find line starting with REQUIRED_ALIAS and extract name of file that # must be created in the $(dir_sampleDb)/qa/ folder. This name will be used further as target database (tmp_fdb). # NOTE: we have to SKIP lines which are commented out, i.e. if they starts with '#': p_required_alias_ptn = re.compile( '^(?!#)((^|\\s+)' + REQUIRED_ALIAS + ')\\s*=\\s*\\$\\(dir_sampleDb\\)/qa/', re.IGNORECASE ) fname_in_dbconf = None with open(act.home_dir/'databases.conf', 'r') as f: for line in f: if p_required_alias_ptn.search(line): # If databases.conf contains line like this: # tmp_4203_alias = $(dir_sampleDb)/qa/tmp_qa_4203.fdb # - then we extract filename: 'tmp_qa_4203.fdb' (see below): fname_in_dbconf = Path(line.split('=')[1].strip()).name break # if 'fname_in_dbconf' remains undefined here then propably REQUIRED_ALIAS not equals to specified in the databases.conf! # assert fname_in_dbconf check_sql = f""" -- DO NOT: set bail on; -- we have to drop database at final point! set list on; rollback; create database '{REQUIRED_ALIAS}'; commit; connect '{REQUIRED_ALIAS}' user {act.db.user}; select mon$sec_database from mon$database; -- must be: 'Self' commit; create mapping mp_existent using plugin Srp from any user to user; create global mapping mg_existent using plugin Srp from any user to user; create user u_existent password '123'; create role r_existent; create domain d_existent as int; create sequence g_existent; create exception e_existent 'foo'; create collation cn_existent for utf8 from unicode; recreate table log_ddl_triggers_activity ( id int generated by default as identity constraint pk_log_ddl_triggers_activity primary key ,ddl_trigger_name varchar(64) ,event_type varchar(25) not null ,object_type varchar(25) not null ,ddl_event varchar(25) not null ,object_name varchar(64) not null ,dts timestamp default 'now' ); create table t_existent ( id int primary key ,pid int ,f01_existent int ,f02_existent int ,f03_existent int ,constraint t_existent_fk foreign key(pid) references t_existent(id) on delete cascade ); create index t_existent_f01 on t_existent(f01_existent); create view v_existent as select * from t_existent; set term ^; create trigger tg_existent for t_existent before insert as begin end ^ create procedure sp_existent as begin end ^ create function fn_existent returns int as begin return 1; end ^ create package pg_existent as begin procedure p; function f returns int; end ^ create package body pg_existent as begin procedure p as begin end function f returns int as begin return 1; end end ^ create package pg_empty as begin procedure p; function f returns int; end ^ commit ^ execute block as declare v_lf char(1) = x'0A'; begin rdb$set_context('USER_SESSION', 'SKIP_DDL_TRIGGER', '1'); for with a as ( select 'ANY DDL STATEMENT' x from rdb$database union all select 'ALTER TABLE' from rdb$database union all select 'DROP MAPPING' from rdb$database union all select 'DROP TABLE' from rdb$database union all select 'DROP PROCEDURE' from rdb$database union all select 'DROP FUNCTION' from rdb$database union all select 'DROP TRIGGER' from rdb$database union all select 'DROP EXCEPTION' from rdb$database union all select 'DROP VIEW' from rdb$database union all select 'DROP DOMAIN' from rdb$database union all select 'DROP ROLE' from rdb$database union all select 'DROP SEQUENCE' from rdb$database union all select 'DROP USER' from rdb$database union all select 'DROP INDEX' from rdb$database union all select 'DROP COLLATION' from rdb$database union all select 'DROP PACKAGE' from rdb$database union all select 'DROP PACKAGE BODY' from rdb$database ) ,e as ( select 'before' w from rdb$database union all select 'after' from rdb$database ) ,t as ( select upper(trim(replace(trim(a.x),' ','_')) || iif(e.w='before', '_before', '_after')) as trg_name, a.x, e.w from e, a ) select 'create trigger trg_' || t.trg_name || ' active ' || t.w || ' ' || trim(t.x) || ' as ' || :v_lf || 'begin' || :v_lf || q'! if (rdb$get_context('USER_SESSION', 'SKIP_DDL_TRIGGER') is null) then!' || :v_lf || ' insert into log_ddl_triggers_activity(ddl_trigger_name, event_type, object_type, ddl_event, object_name) values(' || :v_lf || q'!'!' || trim(t.trg_name) || q'!'!' || :v_lf || q'!, rdb$get_context('DDL_TRIGGER', 'EVENT_TYPE')!' || :v_lf || q'!, rdb$get_context('DDL_TRIGGER', 'OBJECT_TYPE')!' || :v_lf || q'!, rdb$get_context('DDL_TRIGGER', 'DDL_EVENT')!' || :v_lf || q'!, rdb$get_context('DDL_TRIGGER', 'OBJECT_NAME')!' || :v_lf || ');' || :v_lf || ' end' as sttm from t as cursor c do begin execute statement(c.sttm) with autonomous transaction; end rdb$set_context('USER_SESSION', 'SKIP_DDL_TRIGGER', null); end ^ commit ^ set term ;^ --##################################################################### drop mapping if exists mp_existent; drop mapping if exists mp_non_existent; drop global mapping if exists mg_existent; drop global mapping if exists mg_non_existent; drop user if exists u_existent; drop user if exists u_non_existent; drop role if exists r_existent; drop role if exists r_non_existent; drop domain if exists d_existent; drop domain if exists d_non_existent; drop sequence if exists g_existent; drop sequence if exists g_non_existent; drop collation if exists cn_existent; drop collation if exists cn_non_existent; drop index if exists t_existent_f01; -- failed before https://github.com/FirebirdSQL/firebird/commit/a04784d5020326bdd42817eb0c9022b93d364f4a drop index if exists t_non_existent_f01; drop view if exists v_existent; drop view if exists v_non_existent; drop trigger if exists tg_existent; drop trigger if exists tg_non_existent; drop procedure if exists sp_existent; drop procedure if exists sp_non_existent; drop function if exists fn_existent; drop function if exists fn_non_existent; drop package body if exists pg_existent; -- failed before https://github.com/FirebirdSQL/firebird/commit/252a675c2adb95aca4fecb42d7433b39f669c20a drop package body if exists pg_non_existent; -- must be logged because column 'f01_existent' DOES exist: alter table t_existent drop if exists f01_existent ; -- must NOT be logged because column 'g01_non_existent' does NOT exist: alter table t_existent drop if exists g01_non_existent ; -- must be logged because at least one column ('f02_existent') DOES exist: alter table t_existent drop if exists g01_non_existent ,drop if exists g02_non_existent ,drop if exists f02_existent ; commit; set count on; select id ,ddl_trigger_name ,event_type ,object_type ,ddl_event ,object_name from log_ddl_triggers_activity order by id; commit; connect '{REQUIRED_ALIAS}' user {act.db.user}; drop database; quit; """ expected_stdout = f""" MON$SEC_DATABASE Self ID 1 DDL_TRIGGER_NAME DROP_MAPPING_BEFORE EVENT_TYPE DROP OBJECT_TYPE MAPPING DDL_EVENT DROP MAPPING OBJECT_NAME MP_EXISTENT ID 2 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_BEFORE EVENT_TYPE DROP OBJECT_TYPE MAPPING DDL_EVENT DROP MAPPING OBJECT_NAME MP_EXISTENT ID 3 DDL_TRIGGER_NAME DROP_MAPPING_AFTER EVENT_TYPE DROP OBJECT_TYPE MAPPING DDL_EVENT DROP MAPPING OBJECT_NAME MP_EXISTENT ID 4 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_AFTER EVENT_TYPE DROP OBJECT_TYPE MAPPING DDL_EVENT DROP MAPPING OBJECT_NAME MP_EXISTENT ID 5 DDL_TRIGGER_NAME DROP_MAPPING_BEFORE EVENT_TYPE DROP OBJECT_TYPE MAPPING DDL_EVENT DROP MAPPING OBJECT_NAME MG_EXISTENT ID 6 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_BEFORE EVENT_TYPE DROP OBJECT_TYPE MAPPING DDL_EVENT DROP MAPPING OBJECT_NAME MG_EXISTENT ID 7 DDL_TRIGGER_NAME DROP_MAPPING_AFTER EVENT_TYPE DROP OBJECT_TYPE MAPPING DDL_EVENT DROP MAPPING OBJECT_NAME MG_EXISTENT ID 8 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_AFTER EVENT_TYPE DROP OBJECT_TYPE MAPPING DDL_EVENT DROP MAPPING OBJECT_NAME MG_EXISTENT ID 9 DDL_TRIGGER_NAME DROP_USER_BEFORE EVENT_TYPE DROP OBJECT_TYPE USER DDL_EVENT DROP USER OBJECT_NAME U_EXISTENT ID 10 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_BEFORE EVENT_TYPE DROP OBJECT_TYPE USER DDL_EVENT DROP USER OBJECT_NAME U_EXISTENT ID 11 DDL_TRIGGER_NAME DROP_USER_AFTER EVENT_TYPE DROP OBJECT_TYPE USER DDL_EVENT DROP USER OBJECT_NAME U_EXISTENT ID 12 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_AFTER EVENT_TYPE DROP OBJECT_TYPE USER DDL_EVENT DROP USER OBJECT_NAME U_EXISTENT ID 13 DDL_TRIGGER_NAME DROP_USER_BEFORE EVENT_TYPE DROP OBJECT_TYPE USER DDL_EVENT DROP USER OBJECT_NAME U_NON_EXISTENT ID 14 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_BEFORE EVENT_TYPE DROP OBJECT_TYPE USER DDL_EVENT DROP USER OBJECT_NAME U_NON_EXISTENT ID 15 DDL_TRIGGER_NAME DROP_USER_AFTER EVENT_TYPE DROP OBJECT_TYPE USER DDL_EVENT DROP USER OBJECT_NAME U_NON_EXISTENT ID 16 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_AFTER EVENT_TYPE DROP OBJECT_TYPE USER DDL_EVENT DROP USER OBJECT_NAME U_NON_EXISTENT ID 17 DDL_TRIGGER_NAME DROP_ROLE_BEFORE EVENT_TYPE DROP OBJECT_TYPE ROLE DDL_EVENT DROP ROLE OBJECT_NAME R_EXISTENT ID 18 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_BEFORE EVENT_TYPE DROP OBJECT_TYPE ROLE DDL_EVENT DROP ROLE OBJECT_NAME R_EXISTENT ID 19 DDL_TRIGGER_NAME DROP_ROLE_AFTER EVENT_TYPE DROP OBJECT_TYPE ROLE DDL_EVENT DROP ROLE OBJECT_NAME R_EXISTENT ID 20 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_AFTER EVENT_TYPE DROP OBJECT_TYPE ROLE DDL_EVENT DROP ROLE OBJECT_NAME R_EXISTENT ID 21 DDL_TRIGGER_NAME DROP_DOMAIN_BEFORE EVENT_TYPE DROP OBJECT_TYPE DOMAIN DDL_EVENT DROP DOMAIN OBJECT_NAME D_EXISTENT ID 22 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_BEFORE EVENT_TYPE DROP OBJECT_TYPE DOMAIN DDL_EVENT DROP DOMAIN OBJECT_NAME D_EXISTENT ID 23 DDL_TRIGGER_NAME DROP_DOMAIN_AFTER EVENT_TYPE DROP OBJECT_TYPE DOMAIN DDL_EVENT DROP DOMAIN OBJECT_NAME D_EXISTENT ID 24 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_AFTER EVENT_TYPE DROP OBJECT_TYPE DOMAIN DDL_EVENT DROP DOMAIN OBJECT_NAME D_EXISTENT ID 25 DDL_TRIGGER_NAME DROP_SEQUENCE_BEFORE EVENT_TYPE DROP OBJECT_TYPE SEQUENCE DDL_EVENT DROP SEQUENCE OBJECT_NAME G_EXISTENT ID 26 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_BEFORE EVENT_TYPE DROP OBJECT_TYPE SEQUENCE DDL_EVENT DROP SEQUENCE OBJECT_NAME G_EXISTENT ID 27 DDL_TRIGGER_NAME DROP_SEQUENCE_AFTER EVENT_TYPE DROP OBJECT_TYPE SEQUENCE DDL_EVENT DROP SEQUENCE OBJECT_NAME G_EXISTENT ID 28 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_AFTER EVENT_TYPE DROP OBJECT_TYPE SEQUENCE DDL_EVENT DROP SEQUENCE OBJECT_NAME G_EXISTENT ID 29 DDL_TRIGGER_NAME DROP_COLLATION_BEFORE EVENT_TYPE DROP OBJECT_TYPE COLLATION DDL_EVENT DROP COLLATION OBJECT_NAME CN_EXISTENT ID 30 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_BEFORE EVENT_TYPE DROP OBJECT_TYPE COLLATION DDL_EVENT DROP COLLATION OBJECT_NAME CN_EXISTENT ID 31 DDL_TRIGGER_NAME DROP_COLLATION_AFTER EVENT_TYPE DROP OBJECT_TYPE COLLATION DDL_EVENT DROP COLLATION OBJECT_NAME CN_EXISTENT ID 32 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_AFTER EVENT_TYPE DROP OBJECT_TYPE COLLATION DDL_EVENT DROP COLLATION OBJECT_NAME CN_EXISTENT ID 33 DDL_TRIGGER_NAME DROP_INDEX_BEFORE EVENT_TYPE DROP OBJECT_TYPE INDEX DDL_EVENT DROP INDEX OBJECT_NAME T_EXISTENT_F01 ID 34 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_BEFORE EVENT_TYPE DROP OBJECT_TYPE INDEX DDL_EVENT DROP INDEX OBJECT_NAME T_EXISTENT_F01 ID 35 DDL_TRIGGER_NAME DROP_INDEX_AFTER EVENT_TYPE DROP OBJECT_TYPE INDEX DDL_EVENT DROP INDEX OBJECT_NAME T_EXISTENT_F01 ID 36 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_AFTER EVENT_TYPE DROP OBJECT_TYPE INDEX DDL_EVENT DROP INDEX OBJECT_NAME T_EXISTENT_F01 ID 37 DDL_TRIGGER_NAME DROP_VIEW_BEFORE EVENT_TYPE DROP OBJECT_TYPE VIEW DDL_EVENT DROP VIEW OBJECT_NAME V_EXISTENT ID 38 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_BEFORE EVENT_TYPE DROP OBJECT_TYPE VIEW DDL_EVENT DROP VIEW OBJECT_NAME V_EXISTENT ID 39 DDL_TRIGGER_NAME DROP_VIEW_AFTER EVENT_TYPE DROP OBJECT_TYPE VIEW DDL_EVENT DROP VIEW OBJECT_NAME V_EXISTENT ID 40 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_AFTER EVENT_TYPE DROP OBJECT_TYPE VIEW DDL_EVENT DROP VIEW OBJECT_NAME V_EXISTENT ID 41 DDL_TRIGGER_NAME DROP_TRIGGER_BEFORE EVENT_TYPE DROP OBJECT_TYPE TRIGGER DDL_EVENT DROP TRIGGER OBJECT_NAME TG_EXISTENT ID 42 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_BEFORE EVENT_TYPE DROP OBJECT_TYPE TRIGGER DDL_EVENT DROP TRIGGER OBJECT_NAME TG_EXISTENT ID 43 DDL_TRIGGER_NAME DROP_TRIGGER_AFTER EVENT_TYPE DROP OBJECT_TYPE TRIGGER DDL_EVENT DROP TRIGGER OBJECT_NAME TG_EXISTENT ID 44 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_AFTER EVENT_TYPE DROP OBJECT_TYPE TRIGGER DDL_EVENT DROP TRIGGER OBJECT_NAME TG_EXISTENT ID 45 DDL_TRIGGER_NAME DROP_PROCEDURE_BEFORE EVENT_TYPE DROP OBJECT_TYPE PROCEDURE DDL_EVENT DROP PROCEDURE OBJECT_NAME SP_EXISTENT ID 46 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_BEFORE EVENT_TYPE DROP OBJECT_TYPE PROCEDURE DDL_EVENT DROP PROCEDURE OBJECT_NAME SP_EXISTENT ID 47 DDL_TRIGGER_NAME DROP_PROCEDURE_AFTER EVENT_TYPE DROP OBJECT_TYPE PROCEDURE DDL_EVENT DROP PROCEDURE OBJECT_NAME SP_EXISTENT ID 48 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_AFTER EVENT_TYPE DROP OBJECT_TYPE PROCEDURE DDL_EVENT DROP PROCEDURE OBJECT_NAME SP_EXISTENT ID 49 DDL_TRIGGER_NAME DROP_FUNCTION_BEFORE EVENT_TYPE DROP OBJECT_TYPE FUNCTION DDL_EVENT DROP FUNCTION OBJECT_NAME FN_EXISTENT ID 50 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_BEFORE EVENT_TYPE DROP OBJECT_TYPE FUNCTION DDL_EVENT DROP FUNCTION OBJECT_NAME FN_EXISTENT ID 51 DDL_TRIGGER_NAME DROP_FUNCTION_AFTER EVENT_TYPE DROP OBJECT_TYPE FUNCTION DDL_EVENT DROP FUNCTION OBJECT_NAME FN_EXISTENT ID 52 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_AFTER EVENT_TYPE DROP OBJECT_TYPE FUNCTION DDL_EVENT DROP FUNCTION OBJECT_NAME FN_EXISTENT ID 53 DDL_TRIGGER_NAME DROP_PACKAGE_BODY_BEFORE EVENT_TYPE DROP OBJECT_TYPE PACKAGE BODY DDL_EVENT DROP PACKAGE BODY OBJECT_NAME PG_EXISTENT ID 54 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_BEFORE EVENT_TYPE DROP OBJECT_TYPE PACKAGE BODY DDL_EVENT DROP PACKAGE BODY OBJECT_NAME PG_EXISTENT ID 55 DDL_TRIGGER_NAME DROP_PACKAGE_BODY_AFTER EVENT_TYPE DROP OBJECT_TYPE PACKAGE BODY DDL_EVENT DROP PACKAGE BODY OBJECT_NAME PG_EXISTENT ID 56 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_AFTER EVENT_TYPE DROP OBJECT_TYPE PACKAGE BODY DDL_EVENT DROP PACKAGE BODY OBJECT_NAME PG_EXISTENT ID 57 DDL_TRIGGER_NAME ALTER_TABLE_BEFORE EVENT_TYPE ALTER OBJECT_TYPE TABLE DDL_EVENT ALTER TABLE OBJECT_NAME T_EXISTENT ID 58 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_BEFORE EVENT_TYPE ALTER OBJECT_TYPE TABLE DDL_EVENT ALTER TABLE OBJECT_NAME T_EXISTENT ID 59 DDL_TRIGGER_NAME ALTER_TABLE_AFTER EVENT_TYPE ALTER OBJECT_TYPE TABLE DDL_EVENT ALTER TABLE OBJECT_NAME T_EXISTENT ID 60 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_AFTER EVENT_TYPE ALTER OBJECT_TYPE TABLE DDL_EVENT ALTER TABLE OBJECT_NAME T_EXISTENT ID 61 DDL_TRIGGER_NAME ALTER_TABLE_BEFORE EVENT_TYPE ALTER OBJECT_TYPE TABLE DDL_EVENT ALTER TABLE OBJECT_NAME T_EXISTENT ID 62 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_BEFORE EVENT_TYPE ALTER OBJECT_TYPE TABLE DDL_EVENT ALTER TABLE OBJECT_NAME T_EXISTENT ID 63 DDL_TRIGGER_NAME ALTER_TABLE_AFTER EVENT_TYPE ALTER OBJECT_TYPE TABLE DDL_EVENT ALTER TABLE OBJECT_NAME T_EXISTENT ID 64 DDL_TRIGGER_NAME ANY_DDL_STATEMENT_AFTER EVENT_TYPE ALTER OBJECT_TYPE TABLE DDL_EVENT ALTER TABLE OBJECT_NAME T_EXISTENT Records affected: 64 """ act.expected_stdout = expected_stdout act.isql(switches=['-q', act.db.db_path, '-user', act.db.user], input = check_sql, credentials = False, connect_db = False, combine_output = True, io_enc = locale.getpreferredencoding()) assert act.clean_stdout == act.clean_expected_stdout # and act.clean_stderr == act.clean_expected_stderr act.reset()