Skip to content

Commit bd1b175

Browse files
committed
Added/Updated tests\bugs\gh_7137_test.py: Checked on 6.0.0.336, 5.0.1.1383, 4.0.5.3086, 3.0.10.33569 (24.02.2022) - all fine.
1 parent 0e992c7 commit bd1b175

File tree

1 file changed

+110
-0
lines changed

1 file changed

+110
-0
lines changed

tests/bugs/gh_7137_test.py

+110
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,110 @@
1+
#coding:utf-8
2+
3+
"""
4+
ID: issue-7137
5+
ISSUE: https://github.com/FirebirdSQL/firebird/issues/7137
6+
TITLE: Optimizer regression: bad plan (HASH instead of JOIN) is chosen for some inner joins
7+
NOTES:
8+
[26.04.2022] pzotov
9+
Confirmed bug (ineffective execution plan) on 3.0.9.33560 (09.02.2022).
10+
Checked on 6.0.0.336, 5.0.1.1383, 4.0.5.3086, 3.0.10.33569 (24.02.2022) - all fine.
11+
"""
12+
13+
import pytest
14+
from firebird.qa import *
15+
16+
init_sql = """
17+
recreate table test_c(x int);
18+
commit;
19+
20+
recreate table test_a(
21+
id int unique using index test_a_pk
22+
,ico int
23+
,name varchar(50)
24+
);
25+
create index test_a_name on test_a(name);
26+
27+
recreate table test_b(
28+
id int primary key using index test_b_pk
29+
,ico int
30+
,name varchar(50)
31+
);
32+
33+
34+
recreate table test_c(
35+
id int primary key using index test_c_pk
36+
,pid_a int references test_a(id) using index test_c_fk
37+
);
38+
39+
insert into test_a(id, ico, name)
40+
select row_number()over(), mod( row_number()over(), 10 ), ascii_char(64 + mod( row_number()over(), 10 ))
41+
from rdb$types
42+
rows 200;
43+
44+
insert into test_b(id, ico, name)
45+
select row_number()over()-1, mod( row_number()over(), 10 ), ascii_char(64 + mod( row_number()over(), 10 ))
46+
from rdb$types, rdb$types
47+
rows 10000;
48+
49+
insert into test_c(id, pid_a)
50+
select row_number()over(), 1 + mod( row_number()over(), 100 )
51+
from rdb$types, rdb$types
52+
rows 10000;
53+
commit;
54+
55+
set statistics index test_a_pk;
56+
set statistics index test_a_name;
57+
set statistics index test_b_pk;
58+
set statistics index test_c_pk;
59+
set statistics index test_c_fk;
60+
commit;
61+
"""
62+
63+
db = db_factory(init = init_sql)
64+
65+
query_lst = [
66+
"""
67+
select 1
68+
from test_a a
69+
join test_b b on b.ico = a.ico
70+
join test_c c on c.pid_a = a.id
71+
where b.id = 0 and a.name = b.name
72+
""",
73+
]
74+
75+
act = python_act('db')
76+
77+
#---------------------------------------------------------
78+
def replace_leading(source, char="."):
79+
stripped = source.lstrip()
80+
return char * (len(source) - len(stripped)) + stripped
81+
#---------------------------------------------------------
82+
83+
@pytest.mark.version('>=3.0.9')
84+
def test_1(act: Action, capsys):
85+
with act.db.connect() as con:
86+
cur = con.cursor()
87+
for q in query_lst:
88+
with cur.prepare(q) as ps:
89+
print( '\n'.join([replace_leading(s) for s in ps.detailed_plan .split('\n')]) )
90+
91+
expected_stdout = """
92+
Select Expression
93+
....-> Nested Loop Join (inner)
94+
........-> Filter
95+
............-> Table "TEST_B" as "B" Access By ID
96+
................-> Bitmap
97+
....................-> Index "TEST_B_PK" Unique Scan
98+
........-> Filter
99+
............-> Table "TEST_A" as "A" Access By ID
100+
................-> Bitmap
101+
....................-> Index "TEST_A_NAME" Range Scan (full match)
102+
........-> Filter
103+
............-> Table "TEST_C" as "C" Access By ID
104+
................-> Bitmap
105+
....................-> Index "TEST_C_FK" Range Scan (full match)
106+
"""
107+
108+
act.expected_stdout = expected_stdout
109+
act.stdout = capsys.readouterr().out
110+
assert act.clean_stdout == act.clean_expected_stdout

0 commit comments

Comments
 (0)