6
0
mirror of https://github.com/FirebirdSQL/firebird-qa.git synced 2025-01-22 21:43:06 +01:00
firebird-qa/tests/bugs/core_5489_test.py

391 lines
12 KiB
Python
Raw Normal View History

2021-04-26 20:07:00 +02:00
#coding:utf-8
#
# id: bugs.core_5489
# title: Bad performance for NULLs filtering inside a navigational index scan
# decription:
2021-04-26 20:07:00 +02:00
# See prototype and explanations for this test in CORE_5435.fbt
# Confirmed improvement:
#
2021-04-26 20:07:00 +02:00
# 3.0.2.32643, 4.0.0.563:
# **********
# PLAN (TEST ORDER TEST_F01_ID)
# 1 records fetched
# 1143 ms, 2375 read(s), 602376 fetch(es) ---------------- poor :(
# Table Natural Index
# ****************************************************
# TEST 300000
2021-04-26 20:07:00 +02:00
# **********
#
#
2021-04-26 20:07:00 +02:00
# 3.0.2.32708, 4.0.0.572:
# **********
# PLAN (TEST ORDER TEST_F01_ID)
# 0 ms, 22 read(s), 63 fetch(es) --------------------------- cool :)
# Table Natural Index
# ****************************************************
# TEST 20
2021-04-26 20:07:00 +02:00
# **********
#
#
2021-04-26 20:07:00 +02:00
# tracker_id: CORE-5489
# min_versions: ['3.0.2']
# versions: 3.0.2
# qmid: None
import pytest
from firebird.qa import db_factory, python_act, Action
2021-04-26 20:07:00 +02:00
# version: 3.0.2
# resources: None
substitutions_1 = []
init_script_1 = """"""
db_1 = db_factory(page_size=8192, sql_dialect=3, init=init_script_1)
# test_script_1
#---
#
2021-04-26 20:07:00 +02:00
# import os
# import subprocess
# import time
# from fdb import services
# from subprocess import Popen
#
2021-04-26 20:07:00 +02:00
# os.environ["ISC_USER"] = user_name
# os.environ["ISC_PASSWORD"] = user_password
#
2021-04-26 20:07:00 +02:00
# # Obtain engine version:
# engine = str(db_conn.engine_version) # convert to text because 'float' object has no attribute 'startswith'
# db_file = db_conn.database_name
# db_conn.close()
#
2021-04-26 20:07:00 +02:00
# #--------------------------------------------
#
2021-04-26 20:07:00 +02:00
# def flush_and_close( file_handle ):
# # https://docs.python.org/2/library/os.html#os.fsync
# # If you're starting with a Python file object f,
# # first do f.flush(), and
2021-04-26 20:07:00 +02:00
# # then do os.fsync(f.fileno()), to ensure that all internal buffers associated with f are written to disk.
# global os
#
2021-04-26 20:07:00 +02:00
# file_handle.flush()
# if file_handle.mode not in ('r', 'rb') and file_handle.name != os.devnull:
# # otherwise: "OSError: [Errno 9] Bad file descriptor"!
# os.fsync(file_handle.fileno())
# file_handle.close()
#
2021-04-26 20:07:00 +02:00
# #--------------------------------------------
#
2021-04-26 20:07:00 +02:00
# def cleanup( f_names_list ):
# global os
# for i in range(len( f_names_list )):
# if type(f_names_list[i]) == file:
# del_name = f_names_list[i].name
# elif type(f_names_list[i]) == str:
# del_name = f_names_list[i]
# else:
# print('Unrecognized type of element:', f_names_list[i], ' - can not be treated as file.')
# del_name = None
#
2021-04-26 20:07:00 +02:00
# if del_name and os.path.isfile( del_name ):
# os.remove( del_name )
#
2021-04-26 20:07:00 +02:00
# #--------------------------------------------
#
2021-04-26 20:07:00 +02:00
# FETCHES_THRESHOLD = 80
#
2021-04-26 20:07:00 +02:00
# # Change FW to OFF in order to speed up initial data filling:
# ##################
#
2021-04-26 20:07:00 +02:00
# fn_nul = open(os.devnull, 'w')
#
2021-04-26 20:07:00 +02:00
# subprocess.call([ context['fbsvcmgr_path'], "localhost:service_mgr",
# "action_properties", "prp_write_mode", "prp_wm_async",
# "dbname", db_file ],
# stdout = fn_nul,
# stderr = subprocess.STDOUT
# )
#
2021-04-26 20:07:00 +02:00
# fn_nul.close()
#
2021-04-26 20:07:00 +02:00
# #####################
# # Prepare table: add data.
#
2021-04-26 20:07:00 +02:00
# sql_init='''
# recreate table test
# (
# id int not null,
# f01 int,
# f02 int
# );
#
2021-04-26 20:07:00 +02:00
# set term ^;
# create or alter procedure sp_add_init_data(a_rows_to_add int)
# as
# declare n int;
# declare i int = 0;
# begin
# n = a_rows_to_add;
# while ( i < n ) do
# begin
# insert into test(id, f01, f02) values( :i, nullif(mod(:i, :n/20), 0), iif( mod(:i,3)<2, 0, 1) )
# returning :i+1 into i;
# end
# end
# ^
# set term ^;
# commit;
#
2021-04-26 20:07:00 +02:00
# execute procedure sp_add_init_data( 300000 );
# commit;
#
2021-04-26 20:07:00 +02:00
# create index test_f01_id on test(f01, id);
# create index test_f02_only on test(f02);
2021-04-26 20:07:00 +02:00
# commit;
# '''
#
2021-04-26 20:07:00 +02:00
# sql_cmd=open(os.path.join(context['temp_directory'],'tmp_core_5489.sql'), 'w')
# sql_cmd.write(sql_init)
# flush_and_close( sql_cmd )
#
2021-04-26 20:07:00 +02:00
# sql_log=open(os.path.join(context['temp_directory'],'tmp_core_5489.log'),'w')
# sql_err=open(os.path.join(context['temp_directory'],'tmp_core_5489.err'),'w')
#
2021-04-26 20:07:00 +02:00
# subprocess.call([context['isql_path'], dsn, "-i", sql_cmd.name],stdout=sql_log, stderr=sql_err)
#
2021-04-26 20:07:00 +02:00
# flush_and_close( sql_log )
# flush_and_close( sql_err )
#
2021-04-26 20:07:00 +02:00
# #########################
#
2021-04-26 20:07:00 +02:00
# # ::: NB ::: Trace config file format in 3.0 differs from 2.5 one:
# # 1) header section must be enclosed in "[" and "]",
# # 2) parameter-value pairs must be separated with '=' sign:
# # services
# # {
# # parameter = value
# # }
#
2021-04-26 20:07:00 +02:00
# if engine.startswith('2.5'):
# txt = '''# Generated auto, do not edit!
# <database %[\\\\\\\\/]security?.fdb>
# enabled false
# </database>
#
2021-04-26 20:07:00 +02:00
# <database %[\\\\\\\\/]bugs.core_5489.fdb>
# enabled true
# time_threshold 0
# log_statement_finish true
# print_plan true
# print_perf true
# </database>
# '''
# else:
# txt = '''# Generated auto, do not edit!
# database=%[\\\\\\\\/]security?.fdb
# {
# enabled = false
# }
# database=%[\\\\\\\\/]bugs.core_5489.fdb
# {
# enabled = true
# time_threshold = 0
# log_statement_finish = true
# print_plan = true
# print_perf = true
# }
# '''
#
2021-04-26 20:07:00 +02:00
# f_trc_cfg=open( os.path.join(context['temp_directory'],'tmp_trace_5489.cfg'), 'w')
# f_trc_cfg.write(txt)
# flush_and_close( f_trc_cfg )
#
2021-04-26 20:07:00 +02:00
# # ##############################################################
# # S T A R T T R A C E i n S E P A R A T E P R O C E S S
# # ##############################################################
#
2021-04-26 20:07:00 +02:00
# f_trc_log=open( os.path.join(context['temp_directory'],'tmp_trace_5489.log'), "w")
# f_trc_err=open( os.path.join(context['temp_directory'],'tmp_trace_5489.err'), "w")
#
2021-04-26 20:07:00 +02:00
# p_trace = Popen( [ context['fbsvcmgr_path'], 'localhost:service_mgr', 'action_trace_start' , 'trc_cfg', f_trc_cfg.name],stdout=f_trc_log,stderr=f_trc_err)
#
2021-04-26 20:07:00 +02:00
# time.sleep(1)
#
2021-04-26 20:07:00 +02:00
# sql_run='''
# set list on;
# --show version;
# select count(*) cnt_check
2021-04-26 20:07:00 +02:00
# from (
# select *
# from test
2021-04-26 20:07:00 +02:00
# where f01 -- ###################################################################
# IS NULL -- <<< ::: NB ::: we check here 'f01 is NULL', exactly as ticket says.
# and f02=0 -- ###################################################################
# order by f01, id
# )
# ;
# '''
#
2021-04-26 20:07:00 +02:00
# sql_cmd=open(os.path.join(context['temp_directory'],'tmp_core_5489.sql'), 'w')
# sql_cmd.write(sql_run)
# flush_and_close( sql_cmd )
#
2021-04-26 20:07:00 +02:00
# sql_log=open(os.path.join(context['temp_directory'],'tmp_core_5489.log'),'w')
# sql_err=open(os.path.join(context['temp_directory'],'tmp_core_5489.err'),'w')
#
2021-04-26 20:07:00 +02:00
# subprocess.call([context['isql_path'], dsn, "-i", sql_cmd.name],stdout=sql_log, stderr=sql_err)
#
2021-04-26 20:07:00 +02:00
# flush_and_close( sql_log )
# flush_and_close( sql_err )
#
2021-04-26 20:07:00 +02:00
# # ####################################################
# # G E T A C T I V E T R A C E S E S S I O N I D
# # ####################################################
# # Save active trace session info into file for further parsing it and obtain session_id back (for stop):
#
2021-04-26 20:07:00 +02:00
# f_trc_lst = open( os.path.join(context['temp_directory'],'tmp_trace_5489.lst'), 'w')
# subprocess.call([context['fbsvcmgr_path'], 'localhost:service_mgr', 'action_trace_list'], stdout=f_trc_lst)
# flush_and_close( f_trc_lst )
#
2021-04-26 20:07:00 +02:00
# # !!! DO NOT REMOVE THIS LINE !!!
# time.sleep(1)
#
2021-04-26 20:07:00 +02:00
# trcssn=0
# with open( f_trc_lst.name,'r') as f:
# for line in f:
# i=1
# if 'Session ID' in line:
# for word in line.split():
# if i==3:
# trcssn=word
# i=i+1
# break
# # Result: `trcssn` is ID of active trace session. Now we have to terminate it:
#
2021-04-26 20:07:00 +02:00
# # ####################################################
# # S E N D R E Q U E S T T R A C E T O S T O P
# # ####################################################
# if trcssn>0:
# fn_nul = open(os.devnull, 'w')
# subprocess.call([context['fbsvcmgr_path'], 'localhost:service_mgr', 'action_trace_stop','trc_id', trcssn], stdout=fn_nul)
# fn_nul.close()
# # DO NOT REMOVE THIS LINE:
# time.sleep(1)
#
2021-04-26 20:07:00 +02:00
# p_trace.terminate()
# flush_and_close( f_trc_log )
# flush_and_close( f_trc_err )
#
#
2021-04-26 20:07:00 +02:00
# run_with_plan=''
# num_of_fetches=99999999
#
2021-04-26 20:07:00 +02:00
# with open( f_trc_log.name,'r') as f:
# for line in f:
# if line.lower().startswith('plan ('):
# run_with_plan = line.upper()
# if 'fetch(es)' in line:
# words = line.split()
# for k in range(len(words)):
# if words[k].startswith('fetch'):
# num_of_fetches = int( words[k-1] )
#
2021-04-26 20:07:00 +02:00
# print(run_with_plan)
# print( 'Number of fetches: acceptable.'
# if num_of_fetches < FETCHES_THRESHOLD else
2021-04-26 20:07:00 +02:00
# 'Too much fetches %(num_of_fetches)s -- more than threshold = %(FETCHES_THRESHOLD)s' % locals()
# )
#
2021-04-26 20:07:00 +02:00
# # CLEANUP
# #########
# time.sleep(1)
# cleanup( (f_trc_cfg, f_trc_lst, f_trc_log, f_trc_err, sql_log, sql_err, sql_cmd) )
#
2021-04-26 20:07:00 +02:00
#---
act_1 = python_act('db_1', substitutions=substitutions_1)
2021-04-26 20:07:00 +02:00
expected_stdout_1 = """
PLAN (TEST ORDER TEST_F01_ID)
Number of fetches: acceptable.
"""
2021-04-26 20:07:00 +02:00
FETCHES_THRESHOLD = 80
init_sql_1 = """
recreate table test
(
id int not null,
f01 int,
f02 int
);
set term ^;
create or alter procedure sp_add_init_data(a_rows_to_add int)
as
declare n int;
declare i int = 0;
begin
n = a_rows_to_add;
while (i < n) do
begin
insert into test(id, f01, f02) values(:i, nullif(mod(:i, :n/20), 0), iif(mod(:i,3)<2, 0, 1))
returning :i+1 into i;
end
end
^
set term ^;
commit;
2021-04-26 20:07:00 +02:00
execute procedure sp_add_init_data(300000);
commit;
2021-04-26 20:07:00 +02:00
create index test_f01_id on test(f01, id);
create index test_f02_only on test(f02);
commit;
"""
test_script_1 = """
set list on;
select count(*) cnt_check
from (
select *
from test
where f01 -- ###################################################################
IS NULL -- <<< ::: NB ::: we check here 'f01 is NULL', exactly as ticket says.
and f02=0 -- ###################################################################
order by f01, id
) ;
"""
trace_1 = ['time_threshold = 0',
'log_statement_finish = true',
'print_plan = true',
'print_perf = true',
'log_initfini = false',
]
@pytest.mark.version('>=3.0.2')
def test_1(act_1: Action):
act_1.isql(switches=[], input=init_sql_1)
#
with act_1.trace(db_events=trace_1):
act_1.reset()
act_1.isql(switches=[], input=test_script_1)
# Process trace
run_with_plan = ''
num_of_fetches = 99999999
for line in act_1.trace_log:
if line.lower().startswith('plan ('):
run_with_plan = line.strip().upper()
elif 'fetch(es)' in line:
words = line.split()
for k in range(len(words)):
if words[k].startswith('fetch'):
num_of_fetches = int(words[k-1])
# Check
assert run_with_plan == 'PLAN (TEST ORDER TEST_F01_ID)'
assert num_of_fetches < FETCHES_THRESHOLD