#coding:utf-8 """ ID: issue-5912 ISSUE: 5912 TITLE: Parse error when compiling a statement causes memory leak until attachment is disconnected DESCRIPTION: Test uses DDL and query for well known Einstein task. Code of SQL was included inside SP and will be compiled on dynamic basis (using ES mechanism). Syntax error was intentionally added into this code, so actually it will not ever run. After each call of this SP we have to query mon$ tables in order to detect memory leak, but we have to do this TWO times together (and i don't know why it is so). Every even run (2nd, 4th,6 th etc) of this query gave memory leak about ~7...9% in previous version. We repeat in loop of 60 iterations attempt to run SP and then twice query mon$ tables and add results into log. Finally, we check that difference in max_memory* fields is ZERO, or (at least) there can be only one difference more than threshold. After lot of runs this threshold was set to 1.00 (percent) -- see query below. JIRA: CORE-5646 FBTEST: bugs.core_5646 """ import pytest from firebird.qa import * db = db_factory() test_script = """ create or alter view v_memo as select 1 x from rdb$database; recreate sequence g; commit; recreate table memory_usage_log ( seq_no int ,cur_used int ,cur_alloc int ,max_used int ,max_alloc int ); recreate table animal (animal varchar(10) primary key using index pk_animal); recreate table color (color varchar(10) primary key using index pk_color); recreate table drink (drink varchar(10) primary key using index pk_drink); recreate table nation (nation varchar(10) primary key using index pk_nation); recreate table smoke (smoke varchar(10) primary key using index pk_smoke); insert into animal (animal) values ('cat'); insert into animal (animal) values ('fish'); insert into animal (animal) values ('dog'); insert into animal (animal) values ('horse'); insert into animal (animal) values ('bird'); insert into color (color) values ('white'); insert into color (color) values ('yellow'); insert into color (color) values ('red'); insert into color (color) values ('blue'); insert into color (color) values ('green'); insert into drink (drink) values ('cofee'); insert into drink (drink) values ('milk'); insert into drink (drink) values ('water'); insert into drink (drink) values ('beer'); insert into drink (drink) values ('tee'); insert into nation (nation) values ('eng'); insert into nation (nation) values ('swe'); insert into nation (nation) values ('deu'); insert into nation (nation) values ('den'); insert into nation (nation) values ('nor'); insert into smoke (smoke) values ('pall mall'); insert into smoke (smoke) values ('marlboro'); insert into smoke (smoke) values ('rothmans'); insert into smoke (smoke) values ('winfield'); insert into smoke (smoke) values ('dunhill'); commit; set term ^; create or alter procedure sp_invalid_es as declare bad_sql varchar(12000); declare c int; begin bad_sql = 'select count(*) from ( select a1.animal as h1animal, d1.drink as h1drink, n1.nation as h1nation, s1.smoke as h1smoke, c1.color as h1color, a2.animal as h2animal, d2.drink as h2drink, n2.nation as h2nation, s2.smoke as h2smoke, c2.color as h2color, a3.animal as h3animal, d3.drink as h3drink, n3.nation as h3nation, s3.smoke as h3smoke, c3.color as h3color, a4.animal as h4animal, d4.drink as h4drink, n4.nation as h4nation, s4.smoke as h4smoke, c4.color as h4color, a5.animal as h5animal, d5.drink as h5drink, n5.nation as h5nation, s5.smoke as h5smoke, c5.color as h5color from animal a1, drink d1, nation n1, smoke s1, color c1, animal a2, drink d2, nation n2, smoke s2, color c2, animal a3, drink d3, nation n3, smoke s3, color c3, animal a4, drink d4, nation n4, smoke s4, color c4, animal a5, drink d5, nation n5, smoke s5, color c5 where a1.animal <> a2.animal and a1.animal <> a3.animal and a1.animal <> a4.animal and a1.animal <> a5.animal and a2.animal <> a3.animal and a2.animal <> a4.animal and a2.animal <> a5.animal and a3.animal <> a4.animal and a3.animal <> a5.animal and a4.animal <> a5.animal --and and c1.color <> c2.color and c1.color <> c3.color and c1.color <> c4.color and c1.color <> c5.color and c2.color <> c3.color and c2.color <> c4.color and c2.color <> c5.color and c3.color <> c4.color and c3.color <> c5.color and c4.color <> c5.color and d1.drink <> d2.drink and d1.drink <> d3.drink and d1.drink <> d4.drink and d1.drink <> d5.drink and d2.drink <> d3.drink and d2.drink <> d4.drink and d2.drink <> d5.drink and d3.drink <> d4.drink and d3.drink <> d5.drink and d4.drink <> d5.drink and n1.nation <> n2.nation and n1.nation <> n3.nation and n1.nation <> n4.nation and n1.nation <> n5.nation and n2.nation <> n3.nation and n2.nation <> n4.nation and n2.nation <> n5.nation and n3.nation <> n4.nation and n3.nation <> n5.nation and n4.nation <> n5.nation and s1.smoke <> s2.smoke and s1.smoke <> s3.smoke and s1.smoke <> s4.smoke and s1.smoke <> s5.smoke and s2.smoke <> s3.smoke and s2.smoke <> s4.smoke and s2.smoke <> s5.smoke and s3.smoke <> s4.smoke and s3.smoke <> s5.smoke and s4.smoke <> s5.smoke and -- 1 ( (n1.nation = ''eng'' and c1.color = ''red'') or (n2.nation = ''eng'' and c2.color = ''red'') or (n3.nation = ''eng'' and c3.color = ''red'') or (n4.nation = ''eng'' and c4.color = ''red'') or (n5.nation = ''eng'' and c5.color = ''red'') ) and -- 2 ( (n1.nation = ''swe'' and a1.animal = ''dog'') or (n2.nation = ''swe'' and a2.animal = ''dog'') or (n3.nation = ''swe'' and a3.animal = ''dog'') or (n4.nation = ''swe'' and a4.animal = ''dog'') or (n5.nation = ''swe'' and a5.animal = ''dog'') ) and -- 3 ( (n1.nation = ''den'' and d1.drink = ''tee'') or (n2.nation = ''den'' and d2.drink = ''tee'') or (n3.nation = ''den'' and d3.drink = ''tee'') or (n4.nation = ''den'' and d4.drink = ''tee'') or (n5.nation = ''den'' and d5.drink = ''tee'') ) and -- 4 ( (c1.color = ''green'' and c2.color = ''white'') or (c2.color = ''green'' and c3.color = ''white'') or (c3.color = ''green'' and c4.color = ''white'') or (c4.color = ''green'' and c5.color = ''white'') ) and -- 5 ( (c1.color = ''green'' and d1.drink = ''coffee'') or (c2.color = ''green'' and d2.drink = ''coffee'') or (c3.color = ''green'' and d3.drink = ''coffee'') or (c4.color = ''green'' and d4.drink = ''coffee'') or (c5.color = ''green'' and d5.drink = ''coffee'') ) and -- 6 ( (s1.smoke = ''pall mall'' and a1.animal = ''bird'') or (s2.smoke = ''pall mall'' and a2.animal = ''bird'') or (s3.smoke = ''pall mall'' and a3.animal = ''bird'') or (s4.smoke = ''pall mall'' and a4.animal = ''bird'') or (s5.smoke = ''pall mall'' and a5.animal = ''bird'') ) and -- 7 (d3.drink = ''milk'') and -- 8 ( (s1.smoke = ''dunhill'' and c1.color = ''yellow'') or (s2.smoke = ''dunhill'' and c2.color = ''yellow'') or (s3.smoke = ''dunhill'' and c3.color = ''yellow'') or (s4.smoke = ''dunhill'' and c4.color = ''yellow'') or (s5.smoke = ''dunhill'' and c5.color = ''yellow'') ) and -- 9 (n1.nation = ''nor'') and -- 10 ( (s1.smoke = ''marlboro'' and a2.animal = ''cat'') or (s2.smoke = ''marlboro'' and ''cat'' in (a1.animal, a3.animal)) or (s3.smoke = ''marlboro'' and ''cat'' in (a2.animal, a4.animal)) or (s4.smoke = ''marlboro'' and ''cat'' in (a3.animal, a5.animal)) or (s5.smoke = ''marlboro'' and a4.animal = ''cat'') ) and -- 11 ( (s1.smoke = ''dunhill'' and a2.animal = ''horse'') or (s2.smoke = ''dunhill'' and ''cat'' in (a1.animal, a3.animal)) or (s3.smoke = ''dunhill'' and ''cat'' in (a2.animal, a4.animal)) or (s4.smoke = ''dunhill'' and ''cat'' in (a3.animal, a5.animal)) or (s5.smoke = ''dunhill'' and a4.animal = ''horse'') ) and -- 12 ( (s1.smoke = ''winfield'' and d1.drink = ''beer'') or (s2.smoke = ''winfield'' and d2.drink = ''beer'') or (s3.smoke = ''winfield'' and d3.drink = ''beer'') or (s4.smoke = ''winfield'' and d4.drink = ''beer'') or (s5.smoke = ''winfield'' and d5.drink = ''beer'') ) and -- 13 ( (n1.nation = ''nor'' and c2.color = ''blue'') or (n2.nation = ''nor'' and ''blue'' in (c1.color, c3.color)) or (n3.nation = ''nor'' and ''blue'' in (c2.color, c4.color)) or (n4.nation = ''nor'' and ''blue'' in (c3.color, c5.color)) or (n5.nation = ''nor'' and c4.color = ''blue'') ) and -- 14 ( (s1.smoke = ''rothmans'' and n1.nation = ''deu'') or (s2.smoke = ''rothmans'' and n2.nation = ''deu'') or (s3.smoke = ''rothmans'' and n3.nation = ''deu'') or (s4.smoke = ''rothmans'' and n4.nation = ''deu'') or (s5.smoke = ''rothmans'' and n5.nation = ''deu'') ) and -- 15 ( (s1.smoke = ''marlboro'' and d2.drink = ''water'') or (s2.smoke = ''marlboro'' and ''water'' in (d1.drink, d3.drink)) or (s3.smoke = ''marlboro'' and ''water'' in (d2.drink, d4.drink)) or (s4.smoke = ''marlboro'' and ''water'' in (d3.drink, d5.drink)) or (s5.smoke = ''marlboro'' and d4.drink = ''water'') ) and and ) '; execute statement ( bad_sql ) into c; when any do begin end end ^ set term ;^ commit; create or alter view v_memo as select gen_id(g,1) as seq_no ,m.mon$memory_used as cur_used ,m.mon$memory_allocated as cur_alloc ,m.mon$max_memory_used as max_used ,m.mon$max_memory_allocated as max_alloc from mon$attachments a join mon$memory_usage m on a.mon$stat_id = m.mon$stat_id where a.mon$attachment_id = current_connection ; commit; --set list on; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --------------------------------------------------------- commit; execute procedure sp_invalid_es; commit; insert into memory_usage_log select * from v_memo; commit; insert into memory_usage_log select * from v_memo; --####################################################### set list on; set width threshold_violations_count 30; set width diff_percent_in_max_used_memory 50; set width diff_percent_in_max_alloc_memory 50; select seq_no ,iif( violations_cnt > 1, 'POOR: ' || violations_cnt || ' times', 'OK') as threshold_violations_count ,iif( violations_cnt > 1 and diff_used_prc > max_allowed_diff_prc, 'POOR: '|| diff_used_prc ||' - exeeds max allowed percent = ' || max_allowed_diff_prc, 'OK') as diff_percent_in_max_used_memory ,iif( violations_cnt > 1 and diff_alloc_prc > max_allowed_diff_prc, 'POOR: '|| diff_alloc_prc || ' - exeeds max allowed percent = ' || max_allowed_diff_prc , 'OK') as diff_percent_in_max_alloc_memory from ( select a.*, sum( iif(a.diff_used_prc > a.max_allowed_diff_prc or a.diff_alloc_prc > a.max_allowed_diff_prc, 1, 0) )over() as violations_cnt from ( select m.seq_no ,m.max_used ,100.00 * m.max_used / nullif( lag(max_used)over(order by seq_no), 0) - 100 diff_used_prc ,m.max_alloc ,100.00 * m.max_alloc / nullif( lag(max_alloc)over(order by seq_no), 0) - 100 diff_alloc_prc ,1.00 as max_allowed_diff_prc -- ^ -- | ############################## -- +------------------------------------- MAX ALLOWED THRESHOLD, PERCENT -- ############################## from memory_usage_log m ) a --where mod(seq_no,2)=1 and seq_no >= 1 ) where mod(seq_no,2)=1 and seq_no >= 1 order by seq_no ; """ act = isql_act('db', test_script) expected_stdout = """ SEQ_NO 1 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 3 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 5 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 7 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 9 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 11 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 13 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 15 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 17 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 19 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 21 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 23 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 25 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 27 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 29 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 31 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 33 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 35 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 37 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 39 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 41 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 43 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 45 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 47 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 49 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 51 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 53 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 55 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 57 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK SEQ_NO 59 THRESHOLD_VIOLATIONS_COUNT OK DIFF_PERCENT_IN_MAX_USED_MEMORY OK DIFF_PERCENT_IN_MAX_ALLOC_MEMORY OK """ @pytest.mark.version('>=4.0') def test_1(act: Action): act.expected_stdout = expected_stdout act.execute() assert act.clean_stdout == act.clean_expected_stdout