Issue Details (XML | Word | Printable)

Key: CORE-5489
Type: Bug Bug
Status: Closed Closed
Resolution: Fixed
Priority: Major Major
Assignee: Dmitry Yemanov
Reporter: Paquito Ines
Votes: 2
Watchers: 4
Operations

If you were logged in you would be able to see more operations.
Firebird Core

Bad performance for NULLs filtering inside a navigational index scan

Created: 22/Feb/17 05:19 PM   Updated: 25/Mar/17 01:29 PM
Component/s: Engine
Affects Version/s: 3.0.0, 3.0.1
Fix Version/s: 3.0.2, 4.0 Alpha 1

File Attachments: 1. Zip Archive Databases.zip (5.75 MB)


QA Status: Done successfully


 Description  « Hide
When filtering and ordering a query by the same field, Firebird 3 is capable of doing the filtering directly inside the navigational index, but this seems to not be working well if the filtering condition is "is null". In this case, the performance is similar to not using the index. However, the performance is the expected if the filtering condition is "=0", though both queries have the same plan.

This must be tested with Firebird-3.0.2.32664 (nightly build), after correction of CORE-5435. It can also be tested with Firebird 3.0.1 eliminating the "FIELD2=0" condition.

In this example (we have attached in databases.zip the databases for Firebird 2.5 and Firebird 3):
  -Table1 has around 300000 records.
  -Field1 has 15000 different values with 20 records each one.
  -Field2 has 2 different values (0 with 200000 records, and 1 with 100000 records).
  -Both databases were tested immediately after a backup/restore cycle and in the same computer.
  -The times are measured in the second execution of each query (though the first execution follow the same pattern).

Query:
  select *
  from TABLE1 where FIELD1 is null and FIELD2=0
  order by FIELD1, ID

Firebird-3.0.2.32664-0_x64 (nightly build):
  select *
  from TABLE1 where FIELD1 is null and FIELD2=0
  order by FIELD1, ID

  PLAN (TABLE1 ORDER TABLE1_F1_ID)
  Select Expression
      -> Filter
          -> Table "TABLE1" Access By ID
              -> Index "TABLE1_F1_ID" Range Scan (partial match: 1/2)
  0.290 seconds

Firebird-3.0.2.32664-0_x64 (nightly build):
  select *
  from TABLE1 where FIELD1=0 and FIELD2=0
  order by FIELD1, ID;

  PLAN (TABLE1 ORDER TABLE1_F1_ID)
  Select Expression
      -> Filter
          -> Table "TABLE1" Access By ID
              -> Index "TABLE1_F1_ID" Range Scan (partial match: 1/2)
  0.002 s

However, in Firebird 2.5, both "FIELD1 is null" and "FIELD1=0" queries have same plan and same timing:
  PLAN (TABLE1 ORDER TABLE1_F1_ID INDEX (TABLE1_F1_ID))
  0.002 s

-

CREATE TABLE "TABLE1"
(
  "ID" INTEGER NOT NULL,
  "FIELD1" INTEGER,
  "FIELD2" INTEGER,
CONSTRAINT "TABLE1_PK" PRIMARY KEY ("ID")
);

CREATE INDEX "TABLE1_F1_ID" ON "TABLE1"("FIELD1", "ID");
CREATE INDEX "TABLE1_F2" ON "TABLE1"("FIELD2");

 All   Comments   Change History   Subversion Commits      Sort Order: Ascending order - Click to sort in descending order
Dmitry Yemanov added a comment - 22/Feb/17 05:30 PM
In fact, this bug exists in all FB versions. The plan chosen by v2.5 just hides the issue. It manifests itself when:

1) index is compound
2) IS NULL lookup is done using the first segment (partial match)
3) ORDER BY is mapped to the same index (limited navigational scan is performed)