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

"LIKE" queries should use expression index if expression uses system functions e.g. UPPER [CORE6079] #6329

Open
firebird-automations opened this issue Jun 7, 2019 · 4 comments

Comments

@firebird-automations
Copy link
Collaborator

Submitted by: @livius2

CREATE TABLE NAMES
(
NAME VARCHAR(100)
);
commit;
INSERT INTO names
SELECT RF.RDB$FIELD_NAME FROM RDB$RELATION_FIELDS RF;
commit;
CREATE ASCENDING INDEX IXAE_NAMES__NAME ON NAMES COMPUTED BY(UPPER(NAME COLLATE PXW_PLK));
commit;

------------------------------------------------------------------------------------

SELECT * FROM NAMES N WHERE UPPER(http://N.NAME COLLATE PXW_PLK) LIKE 'RDB%SYSTEM_FLAG%'
PLAN (N INDEX (IXAE_NAMES__NAME))
this works as expected

------------------------------------------------------------------------------------
SELECT * FROM NAMES N WHERE UPPER(http://N.NAME COLLATE PXW_PLK) LIKE UPPER('RDB%SYSTEM_FLAG%')
PLAN (N NATURAL)

but this one not - because of function used in LIKE pattern.

------------------------------------------------------------------------------------

I understand current logic, because someone can use custom function and change order of characters.
But system function UPPER does not change anything in like pattern, and index still can be used.
I do not know which other (only system) functions can be used this way but UPPER and LOWER are obvious one.

@firebird-automations
Copy link
Collaborator Author

Modified by: @livius2

priority: Major [ 3 ] => Minor [ 4 ]

@firebird-automations
Copy link
Collaborator Author

Modified by: @livius2

summary: Like should use expression index if pattern is besed on system function e.g. UPPER => "LIKE" should use expression index if pattern is besed on system function e.g. UPPER

@firebird-automations
Copy link
Collaborator Author

Modified by: Sean Leyne (seanleyne)

description: CREATE TABLE NAMES
(
NAME VARCHAR(100)
);
commit;
INSERT INTO names
SELECT RF.RDB$FIELD_NAME FROM RDB$RELATION_FIELDS RF;
commit;
CREATE ASCENDING INDEX IXAE_NAMES__NAME ON NAMES COMPUTED BY(UPPER(NAME COLLATE PXW_PLK));
commit;

------------------------------------------------------------------------------------

SELECT * FROM NAMES N WHERE UPPER(http://N.NAME COLLATE PXW_PLK) LIKE 'RDB%SYSTEM_FLAG%'
PLAN (N INDEX (IXAE_NAMES__NAME))
this works as expected

------------------------------------------------------------------------------------
SELECT * FROM NAMES N WHERE UPPER(http://N.NAME COLLATE PXW_PLK) LIKE UPPER('RDB%SYSTEM_FLAG%')
PLAN (N NATURAL)

but this one not - because of function used in LIKE pattern.

------------------------------------------------------------------------------------

I understand current logic, because someone can use custom function and change order of characters.
But system function UPPER does not change anything in like pattern, and index still can be used.
I do not know which other (only system) functions can be used this way but UPPER and LOWER are obvious one.

=>

CREATE TABLE NAMES
(
NAME VARCHAR(100)
);
commit;
INSERT INTO names
SELECT RF.RDB$FIELD_NAME FROM RDB$RELATION_FIELDS RF;
commit;
CREATE ASCENDING INDEX IXAE_NAMES__NAME ON NAMES COMPUTED BY(UPPER(NAME COLLATE PXW_PLK));
commit;

------------------------------------------------------------------------------------

SELECT * FROM NAMES N WHERE UPPER(http://N.NAME COLLATE PXW_PLK) LIKE 'RDB%SYSTEM_FLAG%'
PLAN (N INDEX (IXAE_NAMES__NAME))
this works as expected

------------------------------------------------------------------------------------
SELECT * FROM NAMES N WHERE UPPER(http://N.NAME COLLATE PXW_PLK) LIKE UPPER('RDB%SYSTEM_FLAG%')
PLAN (N NATURAL)

but this one not - because of function used in LIKE pattern.

------------------------------------------------------------------------------------

I understand current logic, because someone can use custom function and change order of characters.
But system function UPPER does not change anything in like pattern, and index still can be used.
I do not know which other (only system) functions can be used this way but UPPER and LOWER are obvious one.

summary: "LIKE" should use expression index if pattern is besed on system function e.g. UPPER => "LIKE" queries should use expression index if expression uses system functions e.g. UPPER

@dyemanov
Copy link
Member

dyemanov commented Sep 25, 2023

This is not about expression indices, but about indices in general. LIKE can use an index only if it can be converted into STARTING which in turn can happen only if the pattern does not start with a wildcard. Currently, the engine may check this only if the pattern is a string literal, because it's simple. I agree that LOWER/UPPER do not change the order of characters so we could look one level deeper. Another "special cases" could be LEFT, RPAD and maybe even SUBSTRING with startpos == 1 and length >= 1. But for me checking for such exceptions look somewhat fragile.

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