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

266 lines
10 KiB
Python
Raw Normal View History

2021-04-26 20:07:00 +02:00
#coding:utf-8
#
# id: functional.arno.optimizer.opt_full_join_04
# title: FULL OUTER JOIN, list all values, but filtered in WHERE clause
# decription:
2021-04-26 20:07:00 +02:00
# TableX FULL OUTER JOIN TableY with relation in the ON clause.
# Three tables are used, where 1 table (RC) holds references to the two other tables (R and C).
# The two tables R and C contain both 1 value that isn't inside RC.
# =====
# NB: 'UNION ALL' is used here, so PLAN for 2.5 will be of TWO separate rows.
# =====
# Refactored 01-mar-2016. Checked on: WI-V2.5.6.26970, WI-V3.0.0.32366
#
# tracker_id:
2021-04-26 20:07:00 +02:00
# min_versions: ['2.5.0']
# versions: 2.5
# qmid: functional.arno.optimizer.opt_full_join_04
import pytest
from firebird.qa import db_factory, isql_act, Action
# version: 2.5
# resources: None
substitutions_1 = []
init_script_1 = """
create table relations (
relationid integer,
relationname varchar(35)
);
create table categories (
categoryid integer,
description varchar(20)
);
create table relationcategories (
relationid integer,
categoryid integer
);
commit;
insert into relations (relationid, relationname) values (1, 'diving snorkel shop');
insert into relations (relationid, relationname) values (2, 'bakery garbage');
insert into relations (relationid, relationname) values (3, 'racing turtle');
insert into relations (relationid, relationname) values (4, 'folding air-hook shop');
insert into categories (categoryid, description) values (1, 'relation');
insert into categories (categoryid, description) values (2, 'debtor');
insert into categories (categoryid, description) values (3, 'creditor');
insert into categories (categoryid, description) values (4, 'newsletter');
insert into relationcategories (relationid, categoryid) values (1, 1);
insert into relationcategories (relationid, categoryid) values (2, 1);
insert into relationcategories (relationid, categoryid) values (3, 1);
insert into relationcategories (relationid, categoryid) values (1, 2);
insert into relationcategories (relationid, categoryid) values (2, 2);
insert into relationcategories (relationid, categoryid) values (1, 3);
commit;
-- normally these indexes are created by the primary/foreign keys,
-- but we don't want to rely on them for this test
create unique asc index pk_relations on relations (relationid);
create unique asc index pk_categories on categories (categoryid);
create unique asc index pk_relationcategories on relationcategories (relationid, categoryid);
create asc index fk_rc_relations on relationcategories (relationid);
create asc index fk_rc_categories on relationcategories (categoryid);
commit;
"""
2021-04-26 20:07:00 +02:00
db_1 = db_factory(sql_dialect=3, init=init_script_1)
# test_script_1
#---
#
2021-04-26 20:07:00 +02:00
# import os
# import sys
# import time
# import subprocess
#
2021-04-26 20:07:00 +02:00
# os.environ["ISC_USER"] = user_name
# os.environ["ISC_PASSWORD"] = user_password
# engine = str(db_conn.engine_version)
# db_conn.close()
#
2021-04-26 20:07:00 +02:00
# sql_cmd='''
# create table relations (
# relationid integer,
# relationname varchar(35)
# );
#
2021-04-26 20:07:00 +02:00
# create table categories (
# categoryid integer,
# description varchar(20)
# );
#
2021-04-26 20:07:00 +02:00
# create table relationcategories (
# relationid integer,
# categoryid integer
# );
#
2021-04-26 20:07:00 +02:00
# commit;
#
2021-04-26 20:07:00 +02:00
# insert into relations (relationid, relationname) values (1, 'diving snorkel shop');
# insert into relations (relationid, relationname) values (2, 'bakery garbage');
# insert into relations (relationid, relationname) values (3, 'racing turtle');
# insert into relations (relationid, relationname) values (4, 'folding air-hook shop');
#
2021-04-26 20:07:00 +02:00
# insert into categories (categoryid, description) values (1, 'relation');
# insert into categories (categoryid, description) values (2, 'debtor');
# insert into categories (categoryid, description) values (3, 'creditor');
# insert into categories (categoryid, description) values (4, 'newsletter');
#
2021-04-26 20:07:00 +02:00
# insert into relationcategories (relationid, categoryid) values (1, 1);
# insert into relationcategories (relationid, categoryid) values (2, 1);
# insert into relationcategories (relationid, categoryid) values (3, 1);
# insert into relationcategories (relationid, categoryid) values (1, 2);
# insert into relationcategories (relationid, categoryid) values (2, 2);
# insert into relationcategories (relationid, categoryid) values (1, 3);
#
2021-04-26 20:07:00 +02:00
# commit;
#
2021-04-26 20:07:00 +02:00
# -- normally these indexes are created by the primary/foreign keys,
# -- but we don't want to rely on them for this test
# create unique asc index pk_relations on relations (relationid);
# create unique asc index pk_categories on categories (categoryid);
# create unique asc index pk_relationcategories on relationcategories (relationid, categoryid);
# create asc index fk_rc_relations on relationcategories (relationid);
# create asc index fk_rc_categories on relationcategories (categoryid);
#
2021-04-26 20:07:00 +02:00
# commit;
#
2021-04-26 20:07:00 +02:00
# set plan on;
# set list on;
#
2021-04-26 20:07:00 +02:00
# select
# r.relationname,
# rc.relationid,
# rc.categoryid,
# c.description
# from
# relations r
# full join relationcategories rc on (rc.relationid = r.relationid)
# full join categories c on (c.categoryid = rc.categoryid)
# where
# rc.categoryid is null and c.categoryid >= 1
#
2021-04-26 20:07:00 +02:00
# UNION ALL --- ::::::: U N I O N A L L :::::::
#
2021-04-26 20:07:00 +02:00
# select
# r.relationname,
# rc.relationid,
# rc.categoryid,
# c.description
# from
# relations r
# full join relationcategories rc on (rc.relationid = r.relationid)
# full join categories c on (c.categoryid = rc.categoryid)
# where
# rc.relationid is null and r.relationid >= 1;
# '''
#
2021-04-26 20:07:00 +02:00
# f_sql=open( os.path.join(context['temp_directory'],'tmp_opt_full_join_04.tmp'), 'w')
# f_sql.write(sql_cmd)
# f_sql.close()
#
2021-04-26 20:07:00 +02:00
# f_log = open( os.path.join(context['temp_directory'],'tmp_opt_full_join_04.log'), 'w')
#
2021-04-26 20:07:00 +02:00
# subprocess.call( [context['isql_path'], dsn, "-i", f_sql.name],
# stdout=f_log,
# stderr=subprocess.STDOUT
# )
# f_log.close()
# time.sleep(1)
#
2021-04-26 20:07:00 +02:00
# # NB: plan for 2.5 contains TWO rows!
# plan_25_1 = 'PLAN JOIN (C NATURAL, JOIN (RC NATURAL, R INDEX (PK_RELATIONS)))'
# plan_25_2 = 'PLAN JOIN (C INDEX (PK_CATEGORIES), JOIN (RC NATURAL, R NATURAL))'
#
2021-04-26 20:07:00 +02:00
# # plan for 3.0 contains only ONE row:
# plan_30_1 = 'PLAN (JOIN (JOIN (C INDEX (PK_CATEGORIES), JOIN (JOIN (RC NATURAL, R INDEX (PK_RELATIONS)), JOIN (R NATURAL, RC INDEX (FK_RC_RELATIONS)))), JOIN (JOIN (JOIN (RC NATURAL, R INDEX (PK_RELATIONS)), JOIN (R NATURAL, RC INDEX (FK_RC_RELATIONS))), C INDEX (PK_CATEGORIES))), JOIN (JOIN (C NATURAL, JOIN (JOIN (RC NATURAL, R INDEX (PK_RELATIONS)), JOIN (R INDEX (PK_RELATIONS), RC INDEX (FK_RC_RELATIONS)))), JOIN (JOIN (JOIN (RC NATURAL, R INDEX (PK_RELATIONS)), JOIN (R INDEX (PK_RELATIONS), RC INDEX (FK_RC_RELATIONS))), C NATURAL)))'
# plan_30_2 = ''
#
2021-04-26 20:07:00 +02:00
# with open(f_log.name) as f:
# for line in f:
# if line.upper().startswith('PLAN '):
# if engine.startswith('2.'):
# plan_expected_1=plan_25_1
# plan_expected_2=plan_25_2
# else:
# plan_expected_1=plan_30_1
# plan_expected_2=plan_30_2
#
2021-04-26 20:07:00 +02:00
# # Remove trailing whitespaces and newline character:
# if line.upper().rstrip() == plan_expected_1 or line.upper().rstrip() == plan_expected_2:
# if line.upper().rstrip() == plan_expected_1:
# print( 'Actual plan plan coincides with the expected.' )
# else:
# print( 'Actual plan: '+line+' - differs from expected: '+plan_expected)
# else:
# print(line )
#
2021-04-26 20:07:00 +02:00
# # Cleanup
# #########
# os.remove(f_log.name)
# os.remove(f_sql.name)
#
#
2021-04-26 20:07:00 +02:00
#---
test_script_1 = """
set plan on;
set list on;
select
r.relationname,
rc.relationid,
rc.categoryid,
c.description
from
relations r
full join relationcategories rc on (rc.relationid = r.relationid)
full join categories c on (c.categoryid = rc.categoryid)
where
rc.categoryid is null and c.categoryid >= 1
UNION ALL --- ::::::: U N I O N A L L :::::::
select
r.relationname,
rc.relationid,
rc.categoryid,
c.description
from
relations r
full join relationcategories rc on (rc.relationid = r.relationid)
full join categories c on (c.categoryid = rc.categoryid)
where
rc.relationid is null and r.relationid >= 1;
"""
act_1 = isql_act('db_1', test_script_1, substitutions=substitutions_1)
2021-04-26 20:07:00 +02:00
expected_stdout_1 = """
PLAN (JOIN (JOIN (C INDEX (PK_CATEGORIES), JOIN (JOIN (RC NATURAL, R INDEX (PK_RELATIONS)), JOIN (R NATURAL, RC INDEX (FK_RC_RELATIONS)))), JOIN (JOIN (JOIN (RC NATURAL, R INDEX (PK_RELATIONS)), JOIN (R NATURAL, RC INDEX (FK_RC_RELATIONS))), C INDEX (PK_CATEGORIES))), JOIN (JOIN (C NATURAL, JOIN (JOIN (RC NATURAL, R INDEX (PK_RELATIONS)), JOIN (R INDEX (PK_RELATIONS), RC INDEX (FK_RC_RELATIONS)))), JOIN (JOIN (JOIN (RC NATURAL, R INDEX (PK_RELATIONS)), JOIN (R INDEX (PK_RELATIONS), RC INDEX (FK_RC_RELATIONS))), C NATURAL)))
2021-04-26 20:07:00 +02:00
RELATIONNAME <null>
RELATIONID <null>
CATEGORYID <null>
DESCRIPTION newsletter
RELATIONNAME folding air-hook shop
RELATIONID <null>
CATEGORYID <null>
DESCRIPTION <null>
"""
2021-04-26 20:07:00 +02:00
@pytest.mark.version('>=3.0')
def test_1(act_1: Action):
act_1.expected_stdout = expected_stdout_1
act_1.execute()
assert act_1.clean_stdout == act_1.clean_expected_stdout