mirror of
https://github.com/FirebirdSQL/firebird-qa.git
synced 2025-01-22 21:43:06 +01:00
517 lines
22 KiB
Python
517 lines
22 KiB
Python
#coding:utf-8
|
|
|
|
"""
|
|
ID: issue-7494
|
|
ISSUE: https://github.com/FirebirdSQL/firebird/issues/7494
|
|
TITLE: Firebird performance issue - non necessary index reads
|
|
NOTES:
|
|
[11.04.2023] pzotov
|
|
Checked on 3.0.11.33678.
|
|
[12.08.2023] pzotov
|
|
Checked on 4.0.4.2978, 5.0.0.1163. Removed upper boundary for version.
|
|
// was: "Test currently enabled only for FB 3.x. For FB 4.x+ it will be enabled when appropriate commit appear."
|
|
"""
|
|
|
|
import pytest
|
|
from firebird.qa import *
|
|
|
|
db = db_factory()
|
|
|
|
test_script = """
|
|
set bail on;
|
|
set list on;
|
|
recreate table test (id int generated by default as identity, val varchar(32), val2 int);
|
|
commit;
|
|
|
|
insert into test (val, val2) values ('abcd', 1);
|
|
insert into test (val, val2) values ('a', 1);
|
|
insert into test (val, val2) values ('abcde', 1);
|
|
insert into test (val, val2) values ('abcdefgh', 1);
|
|
insert into test (val, val2) values ('abcdefghij', 1);
|
|
insert into test (val, val2) values ('', 1);
|
|
insert into test (val, val2) values ('klmnopqrs', 1);
|
|
insert into test (val, val2) values ('klmnopqr', 1);
|
|
insert into test (val, val2) values ('klmn', 1);
|
|
insert into test (val, val2) values ('efgh', 1);
|
|
commit;
|
|
|
|
create index idx_test_asc on test (val, val2);
|
|
create descending index idx_test_desc on test (val, val2);
|
|
commit;
|
|
|
|
set term ^;
|
|
create or alter procedure sp_test
|
|
(
|
|
query varchar(255), tab varchar(64)
|
|
)
|
|
returns
|
|
(
|
|
ret integer,
|
|
idx_reads integer,
|
|
ok boolean
|
|
)
|
|
as
|
|
declare tx integer;
|
|
declare idx integer;
|
|
begin
|
|
idx = 0;
|
|
idx_reads = 0;
|
|
tx = current_transaction;
|
|
|
|
in autonomous transaction do
|
|
select rs.mon$record_idx_reads
|
|
from mon$table_stats ts join mon$record_stats rs
|
|
on ts.mon$record_stat_id = rs.mon$stat_id
|
|
join mon$transactions tx
|
|
on tx.mon$stat_id = ts.mon$stat_id
|
|
where tx.mon$transaction_id = :tx
|
|
and ts.mon$table_name = :tab
|
|
into :idx;
|
|
|
|
execute statement :query
|
|
into :ret;
|
|
|
|
in autonomous transaction do
|
|
select rs.mon$record_idx_reads
|
|
from mon$table_stats ts join mon$record_stats rs
|
|
on ts.mon$record_stat_id = rs.mon$stat_id
|
|
join mon$transactions tx
|
|
on tx.mon$stat_id = ts.mon$stat_id
|
|
where tx.mon$transaction_id = :tx
|
|
and ts.mon$table_name = :tab
|
|
into :idx_reads;
|
|
|
|
idx_reads = idx_reads - idx;
|
|
|
|
ok = coalesce(ret, 0) = idx_reads;
|
|
suspend;
|
|
end^
|
|
set term ;^
|
|
commit;
|
|
|
|
|
|
WITH q(sql) as
|
|
(
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL >= '''' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL > '''' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL < '''' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL <= '''' ' FROM RDB$DATABASE UNION ALL
|
|
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL >= '''' AND VAL <= ''a'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL > '''' AND VAL <= ''a'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL >= '''' AND VAL < ''a'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL > '''' AND VAL < ''a'' ' FROM RDB$DATABASE UNION ALL
|
|
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL >= '''' AND VAL <= ''abcd'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL > '''' AND VAL <= ''abcd'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL >= '''' AND VAL < ''abcd'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL > '''' AND VAL < ''abcd'' ' FROM RDB$DATABASE UNION ALL
|
|
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL >= ''abcd'' AND VAL <= ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL > ''abcd'' AND VAL <= ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL >= ''abcd'' AND VAL < ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL > ''abcd'' AND VAL < ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL >= ''abcde'' AND VAL <= ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL > ''abcde'' AND VAL <= ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL >= ''abcde'' AND VAL < ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL > ''abcde'' AND VAL < ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL >= ''abcdef'' AND VAL <= ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL > ''abcdef'' AND VAL <= ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL >= ''abcdef'' AND VAL < ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL > ''abcdef'' AND VAL < ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL >= ''abcdefgh'' AND VAL <= ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL > ''abcdefgh'' AND VAL <= ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL >= ''abcdefgh'' AND VAL < ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL > ''abcdefgh'' AND VAL < ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL >= ''efgh'' AND VAL <= ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL > ''efgh'' AND VAL <= ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL >= ''efgh'' AND VAL < ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL > ''efgh'' AND VAL < ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL >= ''klmnopqr'' AND VAL <= ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL > ''klmnopqr'' AND VAL <= ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL >= ''klmnopqr'' AND VAL < ''klmn'' ' FROM RDB$DATABASE UNION ALL
|
|
SELECT 'SELECT COUNT(*) FROM TEST WHERE VAL > ''klmnopqr'' AND VAL < ''klmn'' ' FROM RDB$DATABASE
|
|
)
|
|
|
|
SELECT q.sql, p1.*, p2.*, (p1.ret is not distinct from p2.ret) as correct, p1.ok and p2.ok as efficient
|
|
FROM q left join SP_TEST(sql || ' PLAN (TEST INDEX (IDX_TEST_ASC))', 'TEST') p1 on 1=1
|
|
left join SP_TEST(sql || ' PLAN (TEST INDEX (IDX_TEST_DESC))', 'TEST') p2 on 1=1
|
|
;
|
|
commit;
|
|
"""
|
|
|
|
expected_stdout = """
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL >= ''
|
|
RET 10
|
|
IDX_READS 10
|
|
OK <true>
|
|
RET 10
|
|
IDX_READS 10
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL > ''
|
|
RET 9
|
|
IDX_READS 9
|
|
OK <true>
|
|
RET 9
|
|
IDX_READS 9
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL < ''
|
|
RET 0
|
|
IDX_READS 0
|
|
OK <true>
|
|
RET 0
|
|
IDX_READS 0
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL <= ''
|
|
RET 1
|
|
IDX_READS 1
|
|
OK <true>
|
|
RET 1
|
|
IDX_READS 1
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL >= '' AND VAL <= 'a'
|
|
RET 2
|
|
IDX_READS 2
|
|
OK <true>
|
|
RET 2
|
|
IDX_READS 2
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL > '' AND VAL <= 'a'
|
|
RET 1
|
|
IDX_READS 1
|
|
OK <true>
|
|
RET 1
|
|
IDX_READS 1
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL >= '' AND VAL < 'a'
|
|
RET 1
|
|
IDX_READS 1
|
|
OK <true>
|
|
RET 1
|
|
IDX_READS 1
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL > '' AND VAL < 'a'
|
|
RET 0
|
|
IDX_READS 0
|
|
OK <true>
|
|
RET 0
|
|
IDX_READS 0
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL >= '' AND VAL <= 'abcd'
|
|
RET 3
|
|
IDX_READS 3
|
|
OK <true>
|
|
RET 3
|
|
IDX_READS 3
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL > '' AND VAL <= 'abcd'
|
|
RET 2
|
|
IDX_READS 2
|
|
OK <true>
|
|
RET 2
|
|
IDX_READS 2
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL >= '' AND VAL < 'abcd'
|
|
RET 2
|
|
IDX_READS 2
|
|
OK <true>
|
|
RET 2
|
|
IDX_READS 2
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL > '' AND VAL < 'abcd'
|
|
RET 1
|
|
IDX_READS 1
|
|
OK <true>
|
|
RET 1
|
|
IDX_READS 1
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL >= 'abcd' AND VAL <= 'klmn'
|
|
RET 6
|
|
IDX_READS 6
|
|
OK <true>
|
|
RET 6
|
|
IDX_READS 6
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL > 'abcd' AND VAL <= 'klmn'
|
|
RET 5
|
|
IDX_READS 5
|
|
OK <true>
|
|
RET 5
|
|
IDX_READS 5
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL >= 'abcd' AND VAL < 'klmn'
|
|
RET 5
|
|
IDX_READS 5
|
|
OK <true>
|
|
RET 5
|
|
IDX_READS 5
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL > 'abcd' AND VAL < 'klmn'
|
|
RET 4
|
|
IDX_READS 4
|
|
OK <true>
|
|
RET 4
|
|
IDX_READS 4
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL >= 'abcde' AND VAL <= 'klmn'
|
|
RET 5
|
|
IDX_READS 5
|
|
OK <true>
|
|
RET 5
|
|
IDX_READS 5
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL > 'abcde' AND VAL <= 'klmn'
|
|
RET 4
|
|
IDX_READS 4
|
|
OK <true>
|
|
RET 4
|
|
IDX_READS 4
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL >= 'abcde' AND VAL < 'klmn'
|
|
RET 4
|
|
IDX_READS 4
|
|
OK <true>
|
|
RET 4
|
|
IDX_READS 4
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL > 'abcde' AND VAL < 'klmn'
|
|
RET 3
|
|
IDX_READS 3
|
|
OK <true>
|
|
RET 3
|
|
IDX_READS 3
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL >= 'abcdef' AND VAL <= 'klmn'
|
|
RET 4
|
|
IDX_READS 4
|
|
OK <true>
|
|
RET 4
|
|
IDX_READS 4
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL > 'abcdef' AND VAL <= 'klmn'
|
|
RET 4
|
|
IDX_READS 4
|
|
OK <true>
|
|
RET 4
|
|
IDX_READS 4
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL >= 'abcdef' AND VAL < 'klmn'
|
|
RET 3
|
|
IDX_READS 3
|
|
OK <true>
|
|
RET 3
|
|
IDX_READS 3
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL > 'abcdef' AND VAL < 'klmn'
|
|
RET 3
|
|
IDX_READS 3
|
|
OK <true>
|
|
RET 3
|
|
IDX_READS 3
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL >= 'abcdefgh' AND VAL <= 'klmn'
|
|
RET 4
|
|
IDX_READS 4
|
|
OK <true>
|
|
RET 4
|
|
IDX_READS 4
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL > 'abcdefgh' AND VAL <= 'klmn'
|
|
RET 3
|
|
IDX_READS 3
|
|
OK <true>
|
|
RET 3
|
|
IDX_READS 3
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL >= 'abcdefgh' AND VAL < 'klmn'
|
|
RET 3
|
|
IDX_READS 3
|
|
OK <true>
|
|
RET 3
|
|
IDX_READS 3
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL > 'abcdefgh' AND VAL < 'klmn'
|
|
RET 2
|
|
IDX_READS 2
|
|
OK <true>
|
|
RET 2
|
|
IDX_READS 2
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL >= 'efgh' AND VAL <= 'klmn'
|
|
RET 2
|
|
IDX_READS 2
|
|
OK <true>
|
|
RET 2
|
|
IDX_READS 2
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL > 'efgh' AND VAL <= 'klmn'
|
|
RET 1
|
|
IDX_READS 1
|
|
OK <true>
|
|
RET 1
|
|
IDX_READS 1
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL >= 'efgh' AND VAL < 'klmn'
|
|
RET 1
|
|
IDX_READS 1
|
|
OK <true>
|
|
RET 1
|
|
IDX_READS 1
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL > 'efgh' AND VAL < 'klmn'
|
|
RET 0
|
|
IDX_READS 0
|
|
OK <true>
|
|
RET 0
|
|
IDX_READS 0
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL >= 'klmnopqr' AND VAL <= 'klmn'
|
|
RET 0
|
|
IDX_READS 0
|
|
OK <true>
|
|
RET 0
|
|
IDX_READS 0
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL > 'klmnopqr' AND VAL <= 'klmn'
|
|
RET 0
|
|
IDX_READS 0
|
|
OK <true>
|
|
RET 0
|
|
IDX_READS 0
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL >= 'klmnopqr' AND VAL < 'klmn'
|
|
RET 0
|
|
IDX_READS 0
|
|
OK <true>
|
|
RET 0
|
|
IDX_READS 0
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
|
|
SQL SELECT COUNT(*) FROM TEST WHERE VAL > 'klmnopqr' AND VAL < 'klmn'
|
|
RET 0
|
|
IDX_READS 0
|
|
OK <true>
|
|
RET 0
|
|
IDX_READS 0
|
|
OK <true>
|
|
CORRECT <true>
|
|
EFFICIENT <true>
|
|
"""
|
|
|
|
act = isql_act('db', test_script)
|
|
|
|
@pytest.mark.version('>=3.0.11')
|
|
def test_1(act: Action):
|
|
act.expected_stdout = expected_stdout
|
|
act.execute(combine_output = True)
|
|
assert act.clean_stdout == act.clean_expected_stdout
|