Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Choose the best matching index for navigation [CORE4285] #4608

Closed
firebird-issue-importer opened this issue Nov 28, 2013 · 8 comments
Closed

Comments

@firebird-issue-importer

Submitted by: @dyemanov

Relate to QA466

Votes: 1

Currently, when ORDER plan is in game, the optimizer chooses the first index candidate that matches the ORDER BY / GROUP BY clause. This is not the best approach when multiple index choices are available, see examples below.

create table test (col1 int, col2 int, col3 int);
create index itestcol1 on test (col1);
create index itestcol12 on test (col1, col2);
create index itestcol21 on test (col2, col1);
create index itestcol123 on test (col1, col2, col3);
create index itestcol132 on test (col1, col3, col2);
set planonly;

select 1 from test order by col1;
-- expected: PLAN (TEST ORDER ITESTCOL1)

select 1 from test where col1 = 0 order by col1;
-- expected: PLAN (TEST ORDER ITESTCOL1)

select 1 from test order by col1, col2;
-- expected: PLAN (TEST ORDER ITESTCOL12)

select 1 from test where col1 = 0 order by col1, col2;
-- expected: PLAN (TEST ORDER ITESTCOL12)

select 1 from test where col1 = 0 and col2 = 0 order by col1, col2;
-- expected: PLAN (TEST ORDER ITESTCOL12)

select 1 from test order by col1, col2, col3;
-- expected: PLAN (TEST ORDER ITESTCOL123)

select 1 from test where col1 = 0 order by col1, col2, col3;
-- expected: PLAN (TEST ORDER ITESTCOL123)

select 1 from test where col1 = 0 and col2 = 0 order by col1, col2, col3;
-- expected: PLAN (TEST ORDER ITESTCOL123)

select 1 from test where col1 = 0 and col2 = 0 order by col1;
-- expected: PLAN (TEST ORDER ITESTCOL12)
-- NOTE: PLAN (TEST ORDER ITESTCOL21) becomes also possible after resolving CORE1846

select 1 from test where col1 = 0 and col2 = 0 and col3 = 0 order by col1;
-- expected: PLAN (TEST ORDER ITESTCOL123) or PLAN (TEST ORDER ITESTCOL132)

select 1 from test where col1 = 0 and col3 = 0 order by col1;
-- expected: PLAN (TEST ORDER ITESTCOL132)

select 1 from test where col1 = 0 and col3 = 0 order by col1, col2;
-- expected: PLAN (TEST ORDER ITESTCOL12)
-- NOTE: PLAN (TEST ORDER ITESTCOL132) becomes also possible after resolving CORE1846

select 1 from test where col1 = 0 and col3 = 0 order by col1, col2, col3;
-- expected: PLAN (TEST ORDER ITESTCOL123)

select 1 from test where col1 = 0 and col3 = 0 order by col1, col3;
-- expected: PLAN (TEST ORDER ITESTCOL132)

Commits: 74fbaf5 FirebirdSQL/fbt-repository@77c08a3 FirebirdSQL/fbt-repository@b2d0198

@firebird-issue-importer
Copy link
Author

firebird-issue-importer commented Nov 28, 2013

Modified by: @dyemanov

assignee: Dmitry Yemanov [ dimitr ]

@firebird-issue-importer
Copy link
Author

firebird-issue-importer commented Nov 28, 2013

Modified by: @dyemanov

status: Open [ 1 ] => Resolved [ 5 ]

resolution: Fixed [ 1 ]

Fix Version: 3.0 Alpha 2 [ 10560 ]

@firebird-issue-importer
Copy link
Author

firebird-issue-importer commented Nov 28, 2013

Modified by: @dyemanov

description: Currently, when ORDER plan is in game, the optimizer chooses the first index candidate that matches the ORDER BY / GROUP BY clause. This is not the best approach when multiple index choices are available, see examples below.

create table test (col1 int, col2 int, col3 int);
create index itestcol1 on test (col1);
create index itestcol12 on test (col1, col2);
create index itestcol21 on test (col2, col1);
create index itestcol123 on test (col1, col2, col3);
create index itestcol132 on test (col1, col3, col2);
set planonly;

select 1 from test order by col1;
-- expected: PLAN (TEST ORDER ITESTCOL1)

select 1 from test where col1 = 0 order by col1;
-- expected: PLAN (TEST ORDER ITESTCOL1)

select 1 from test order by col1, col2;
-- expected: PLAN (TEST ORDER ITESTCOL12)

select 1 from test where col1 = 0 order by col1, col2;
-- expected: PLAN (TEST ORDER ITESTCOL12)

select 1 from test where col1 = 0 and col2 = 0 order by col1, col2;
-- expected: PLAN (TEST ORDER ITESTCOL12)

select 1 from test order by col1, col2, col3;
-- expected: PLAN (TEST ORDER ITESTCOL123)

select 1 from test where col1 = 0 order by col1, col2, col3;
-- expected: PLAN (TEST ORDER ITESTCOL123)

select 1 from test where col1 = 0 and col2 = 0 order by col1, col2, col3;
-- expected: PLAN (TEST ORDER ITESTCOL123)

select 1 from test where col1 = 0 and col2 = 0 order by col1;
-- expected: PLAN (TEST ORDER ITESTCOL12)

select 1 from test where col1 = 0 and col2 = 0 and col3 = 0 order by col1;
-- expected: PLAN (TEST ORDER ITESTCOL123) or PLAN (TEST ORDER ITESTCOL132)

select 1 from test where col1 = 0 and col3 = 0 order by col1;
-- expected: PLAN (TEST ORDER ITESTCOL132)

select 1 from test where col1 = 0 and col3 = 0 order by col1, col2;
-- expected: PLAN (TEST ORDER ITESTCOL12)

select 1 from test where col1 = 0 and col3 = 0 order by col1, col2, col3;
-- expected: PLAN (TEST ORDER ITESTCOL123)

select 1 from test where col1 = 0 and col3 = 0 order by col1, col3;
-- expected: PLAN (TEST ORDER ITESTCOL132)

=>

Currently, when ORDER plan is in game, the optimizer chooses the first index candidate that matches the ORDER BY / GROUP BY clause. This is not the best approach when multiple index choices are available, see examples below.

create table test (col1 int, col2 int, col3 int);
create index itestcol1 on test (col1);
create index itestcol12 on test (col1, col2);
create index itestcol21 on test (col2, col1);
create index itestcol123 on test (col1, col2, col3);
create index itestcol132 on test (col1, col3, col2);
set planonly;

select 1 from test order by col1;
-- expected: PLAN (TEST ORDER ITESTCOL1)

select 1 from test where col1 = 0 order by col1;
-- expected: PLAN (TEST ORDER ITESTCOL1)

select 1 from test order by col1, col2;
-- expected: PLAN (TEST ORDER ITESTCOL12)

select 1 from test where col1 = 0 order by col1, col2;
-- expected: PLAN (TEST ORDER ITESTCOL12)

select 1 from test where col1 = 0 and col2 = 0 order by col1, col2;
-- expected: PLAN (TEST ORDER ITESTCOL12)

select 1 from test order by col1, col2, col3;
-- expected: PLAN (TEST ORDER ITESTCOL123)

select 1 from test where col1 = 0 order by col1, col2, col3;
-- expected: PLAN (TEST ORDER ITESTCOL123)

select 1 from test where col1 = 0 and col2 = 0 order by col1, col2, col3;
-- expected: PLAN (TEST ORDER ITESTCOL123)

select 1 from test where col1 = 0 and col2 = 0 order by col1;
-- expected: PLAN (TEST ORDER ITESTCOL12)
-- NOTE: PLAN (TEST ORDER ITESTCOL21) becomes also possible after resolving CORE1846

select 1 from test where col1 = 0 and col2 = 0 and col3 = 0 order by col1;
-- expected: PLAN (TEST ORDER ITESTCOL123) or PLAN (TEST ORDER ITESTCOL132)

select 1 from test where col1 = 0 and col3 = 0 order by col1;
-- expected: PLAN (TEST ORDER ITESTCOL132)

select 1 from test where col1 = 0 and col3 = 0 order by col1, col2;
-- expected: PLAN (TEST ORDER ITESTCOL12)
-- NOTE: PLAN (TEST ORDER ITESTCOL132) becomes also possible after resolving CORE1846

select 1 from test where col1 = 0 and col3 = 0 order by col1, col2, col3;
-- expected: PLAN (TEST ORDER ITESTCOL123)

select 1 from test where col1 = 0 and col3 = 0 order by col1, col3;
-- expected: PLAN (TEST ORDER ITESTCOL132)

@firebird-issue-importer
Copy link
Author

firebird-issue-importer commented Nov 29, 2013

Modified by: @pmakowski

Link: This issue block progress on QA466 [ QA466 ]

@firebird-issue-importer
Copy link
Author

firebird-issue-importer commented Nov 29, 2013

Modified by: @pmakowski

Link: This issue block progress on QA466 [ QA466 ] =>

@firebird-issue-importer
Copy link
Author

firebird-issue-importer commented Nov 29, 2013

Modified by: @pmakowski

Link: This issue relate to QA466 [ QA466 ]

@firebird-issue-importer
Copy link
Author

firebird-issue-importer commented Apr 10, 2014

Modified by: @pmakowski

status: Resolved [ 5 ] => Closed [ 6 ]

@firebird-issue-importer
Copy link
Author

firebird-issue-importer commented Jul 10, 2015

Modified by: @pavel-zotov

status: Closed [ 6 ] => Closed [ 6 ]

QA Status: Done successfully

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Projects
None yet
Development

No branches or pull requests

2 participants