|
| 1 | +#coding:utf-8 |
| 2 | + |
| 3 | +""" |
| 4 | +ID: issue-7466 |
| 5 | +ISSUE: https://github.com/FirebirdSQL/firebird/issues/7466 |
| 6 | +TITLE: Add COMPILE trace events - ability to see execution plan of every PSQL statement. |
| 7 | +DESCRIPTION: |
| 8 | + Separate test for check appearance of execution plans of every statement inside compiled PSQL unit, see: |
| 9 | + https://github.com/FirebirdSQL/firebird/pull/7466#issue-1564439735 |
| 10 | + Test creates stored procedure with several satements in it that use tables. Statements have no any sense. |
| 11 | + We check here that compiling of this SP leads to appearing in the trace execution plans for every statement. |
| 12 | +NOTES: |
| 13 | + [18-aug-2023] pzotov |
| 14 | + 1. It must be noted that the term 'COMPILE' means parsing of BLR code into an execution tree, i.e. this action |
| 15 | + occurs when unit code is loaded into metadata cache. |
| 16 | + 2. All subqueries like EXISTS() or IN() (and their "not" form) will be displayed in the trace as "separate" block |
| 17 | + followed by block with "Select expression" or "Cursor". This seems not readable but currently it is so. |
| 18 | + 3. Number of lines and columns for 'Subquery' will be shown only when this subquery is used as part PSQL statement |
| 19 | + (i.e. not as part of SQL query) -- see 'decode()' below: |
| 20 | + ======= |
| 21 | + Sub-query (line 37, column 26) |
| 22 | + -> Singularity Check |
| 23 | + ... |
| 24 | + ======= |
| 25 | + 4. Plans, of course, can be changed in the future, so this test must be adjusted if this will occur. |
| 26 | + |
| 27 | + Thanks to dimitr for explanations. |
| 28 | + Discussed with dimitr, letters 18.08.2023. |
| 29 | +
|
| 30 | + Checked on 5.0.0.1164 |
| 31 | +""" |
| 32 | +import locale |
| 33 | +import re |
| 34 | +import pytest |
| 35 | +from firebird.qa import * |
| 36 | + |
| 37 | +db = db_factory() |
| 38 | + |
| 39 | +substitutions = [ |
| 40 | + (' \\(line \\d+, column \\d+\\)', '(line, column)' ) |
| 41 | + ,( '\\s+\\d+\\s+ms', '') |
| 42 | + ] |
| 43 | + |
| 44 | +act = python_act('db', substitutions = substitutions) |
| 45 | + |
| 46 | +trace = ['log_initfini = false', |
| 47 | + 'log_errors = true', |
| 48 | + 'time_threshold = 0', |
| 49 | + 'log_procedure_compile = true', |
| 50 | + 'print_plan = true', |
| 51 | + 'explain_plan = true', |
| 52 | + ] |
| 53 | + |
| 54 | +@pytest.mark.version('>=5.0') |
| 55 | +def test_1(act: Action, capsys): |
| 56 | + |
| 57 | + test_script = f""" |
| 58 | + create table tmain(id int primary key using index tmain_pk, x int); |
| 59 | + create table tdetl(id int primary key using index tdetl_pk, pid int references tmain using index tdetl_fk, y int, z int); |
| 60 | + insert into tmain(id,x) select row_number()over(), -100 + rand()*200 from rdb$types rows 100; |
| 61 | + insert into tdetl(id, pid, y,z) select row_number()over(), 1+rand()*99, rand()*1000, rand()*1000 from rdb$types; |
| 62 | + commit; |
| 63 | + create index tmain_x on tmain(x); |
| 64 | + create index tdetl_y on tdetl(y); |
| 65 | + create index tdetl_z on tdetl(z); |
| 66 | +
|
| 67 | + set statistics index tdetl_fk; |
| 68 | + commit; |
| 69 | +
|
| 70 | + set term ^; |
| 71 | + create or alter procedure sp_test returns(id int, c int) |
| 72 | + as |
| 73 | + declare k cursor for ( |
| 74 | + select m4.id, d4.y, d4.z |
| 75 | + from tmain m4 |
| 76 | + cross join lateral ( |
| 77 | + select y, z |
| 78 | + from tdetl dx |
| 79 | + where |
| 80 | + dx.pid = m4.id |
| 81 | + and m4.x between dx.y and dx.z |
| 82 | + ) d4 |
| 83 | + where exists(select count(*) from tdetl dy group by dy.pid having count(*) > 2) |
| 84 | + ); |
| 85 | + begin |
| 86 | +
|
| 87 | + if ( not exists(select * from tmain m0 where m0.x > 0) ) then |
| 88 | + exception; |
| 89 | +
|
| 90 | + ---------------------------- |
| 91 | +
|
| 92 | + with recursive |
| 93 | + r as ( |
| 94 | + select 0 as i, d0.id, d0.pid |
| 95 | + from tdetl d0 |
| 96 | + where d0.pid is null |
| 97 | + UNION ALL |
| 98 | + select r.i + 1, dx.id, dx.pid |
| 99 | + from tdetl dx |
| 100 | + join r on dx.pid = r.id |
| 101 | + where exists(select * from tmain m0a where m0a.id <> dx.pid and m0a.x in(dx.y, dx.z) ) |
| 102 | + ) |
| 103 | + select count(*) from r where r.i > 2 |
| 104 | + into c; |
| 105 | +
|
| 106 | + ---------------------------- |
| 107 | + c = decode( (select mod(count(*), 3) from tmain m1a) |
| 108 | + ,0, (select min(x) from tmain m1b) |
| 109 | + ,1, (select min(d1b.pid) from tdetl d1b) |
| 110 | + ,2, (select max(d1c.pid) from tdetl d1c) |
| 111 | + ); |
| 112 | +
|
| 113 | + ---------------------------- |
| 114 | + for |
| 115 | + select m2.id, count(*) |
| 116 | + from tmain m2 |
| 117 | + join tdetl d using(id) |
| 118 | + where m2.x > 0 |
| 119 | + group by 1 |
| 120 | + into id, c |
| 121 | + do |
| 122 | + suspend; |
| 123 | + ---------------------------- |
| 124 | + for |
| 125 | + select m3.id, 0 |
| 126 | + from tmain m3 |
| 127 | + where |
| 128 | + m3.x > 0 and |
| 129 | + not exists(select * from tdetl d where d.pid = m3.id) |
| 130 | + into id, c |
| 131 | + do |
| 132 | + suspend; |
| 133 | + end |
| 134 | + ^ |
| 135 | + set term ;^ |
| 136 | + commit; |
| 137 | + """ |
| 138 | + |
| 139 | + with act.trace(db_events=trace, encoding = locale.getpreferredencoding(), encoding_errors='utf8'): |
| 140 | + act.isql(switches = ['-q'], input = test_script, combine_output = True, io_enc = locale.getpreferredencoding()) |
| 141 | + |
| 142 | + # Process trace |
| 143 | + start_show = 0 |
| 144 | + for line in act.trace_log: |
| 145 | + if line.startswith("^^^"): |
| 146 | + start_show = 1 |
| 147 | + continue |
| 148 | + if start_show and line.rstrip().split(): |
| 149 | + print(line) |
| 150 | + |
| 151 | + expected_stdout = f""" |
| 152 | + Sub-query (invariant) |
| 153 | + -> Filter |
| 154 | + -> Aggregate |
| 155 | + -> Table "TDETL" as "K DY" Access By ID |
| 156 | + -> Index "TDETL_FK" Full Scan |
| 157 | + Cursor "K" (line 3, column 13) |
| 158 | + -> Filter (preliminary) |
| 159 | + -> Nested Loop Join (inner) |
| 160 | + -> Table "TMAIN" as "K M4" Full Scan |
| 161 | + -> Filter |
| 162 | + -> Table "TDETL" as "K D4 DX" Access By ID |
| 163 | + -> Bitmap And |
| 164 | + -> Bitmap |
| 165 | + -> Index "TDETL_FK" Range Scan (full match) |
| 166 | + -> Bitmap |
| 167 | + -> Index "TDETL_Y" Range Scan (upper bound: 1/1) |
| 168 | + Sub-query |
| 169 | + -> Filter |
| 170 | + -> Table "TMAIN" as "M0" Access By ID |
| 171 | + -> Bitmap |
| 172 | + -> Index "TMAIN_X" Range Scan (lower bound: 1/1) |
| 173 | + Sub-query |
| 174 | + -> Filter |
| 175 | + -> Table "TMAIN" as "R M0A" Access By ID |
| 176 | + -> Bitmap Or |
| 177 | + -> Bitmap |
| 178 | + -> Index "TMAIN_X" Range Scan (full match) |
| 179 | + -> Bitmap |
| 180 | + -> Index "TMAIN_X" Range Scan (full match) |
| 181 | + Select Expression (line 22, column 13) |
| 182 | + -> Singularity Check |
| 183 | + -> Aggregate |
| 184 | + -> Filter |
| 185 | + -> Recursion |
| 186 | + -> Filter |
| 187 | + -> Table "TDETL" as "R D0" Access By ID |
| 188 | + -> Bitmap |
| 189 | + -> Index "TDETL_FK" Range Scan (full match) |
| 190 | + -> Filter |
| 191 | + -> Table "TDETL" as "R DX" Access By ID |
| 192 | + -> Bitmap |
| 193 | + -> Index "TDETL_FK" Range Scan (full match) |
| 194 | + Sub-query (line 37, column 26) |
| 195 | + -> Singularity Check |
| 196 | + -> Aggregate |
| 197 | + -> Table "TMAIN" as "M1A" Full Scan |
| 198 | + Sub-query (line 38, column 30) |
| 199 | + -> Singularity Check |
| 200 | + -> Aggregate |
| 201 | + -> Table "TMAIN" as "M1B" Access By ID |
| 202 | + -> Index "TMAIN_X" Full Scan |
| 203 | + Sub-query (line 39, column 30) |
| 204 | + -> Singularity Check |
| 205 | + -> Aggregate |
| 206 | + -> Table "TDETL" as "D1B" Access By ID |
| 207 | + -> Index "TDETL_FK" Full Scan |
| 208 | + Sub-query (line 40, column 30) |
| 209 | + -> Singularity Check |
| 210 | + -> Aggregate |
| 211 | + -> Table "TDETL" as "D1C" Full Scan |
| 212 | + Select Expression (line 44, column 13) |
| 213 | + -> Aggregate |
| 214 | + -> Nested Loop Join (inner) |
| 215 | + -> Filter |
| 216 | + -> Table "TMAIN" as "M2" Access By ID |
| 217 | + -> Index "TMAIN_PK" Full Scan |
| 218 | + -> Bitmap |
| 219 | + -> Index "TMAIN_X" Range Scan (lower bound: 1/1) |
| 220 | + -> Filter |
| 221 | + -> Table "TDETL" as "D" Access By ID |
| 222 | + -> Bitmap |
| 223 | + -> Index "TDETL_PK" Unique Scan |
| 224 | + Sub-query |
| 225 | + -> Filter |
| 226 | + -> Table "TDETL" as "D" Access By ID |
| 227 | + -> Bitmap |
| 228 | + -> Index "TDETL_FK" Range Scan (full match) |
| 229 | + Select Expression (line 54, column 13) |
| 230 | + -> Filter |
| 231 | + -> Table "TMAIN" as "M3" Access By ID |
| 232 | + -> Bitmap |
| 233 | + -> Index "TMAIN_X" Range Scan (lower bound: 1/1) |
| 234 | + 0 ms |
| 235 | + """ |
| 236 | + |
| 237 | + act.expected_stdout = expected_stdout |
| 238 | + act.stdout = capsys.readouterr().out |
| 239 | + assert act.clean_stdout == act.clean_expected_stdout |
0 commit comments