Simple Plans
The simplest plans consist of a relation name followed by a retrieval method.For example, for an unsorted single-table select without a WHERE
clause:
select * from students
plan (students natural);
Advanced plan:
Select Expression -> Table "STUDENTS" Full Scan
If there’s a WHERE
or a HAVING
clause, you can specify the index to be used for finding matches:
select * from students
where class = '3C'
plan (students index (ix_stud_class));
Advanced plan:
Select Expression -> Filter -> Table "STUDENTS" Access By ID -> Bitmap -> Index "IX_STUD_CLASS" Range Scan (full match)
The INDEX
directive is also used for join conditions (to be discussed a little later).It can contain a list of indexes, separated by commas.
ORDER
specifies the index for sorting the set if an ORDER BY
or GROUP BY
clause is present:
select * from students
plan (students order pk_students)
order by id;
Advanced plan:
Select Expression -> Table "STUDENTS" Access By ID -> Index "PK_STUDENTS" Full Scan
ORDER
and INDEX
can be combined:
select * from students
where class >= '3'
plan (students order pk_students index (ix_stud_class))
order by id;
Advanced plan:
Select Expression -> Filter -> Table "STUDENTS" Access By ID -> Index "PK_STUDENTS" Full Scan -> Bitmap -> Index "IX_STUD_CLASS" Range Scan (lower bound: 1/1)
It is perfectly OK if ORDER
and INDEX
specify the same index:
select * from students
where class >= '3'
plan (students order ix_stud_class index (ix_stud_class))
order by class;
Advanced plan:
Select Expression -> Filter -> Table "STUDENTS" Access By ID -> Index "IX_STUD_CLASS" Range Scan (lower bound: 1/1) -> Bitmap -> Index "IX_STUD_CLASS" Range Scan (lower bound: 1/1)
For sorting sets when there’s no usable index available (or if you want to suppress its use), leave out ORDER
and prepend the plan expression with SORT
:
select * from students
plan sort (students natural)
order by name;
Advanced plan:
Select Expression -> Sort (record length: 128, key length: 56) -> Table "STUDENTS" Full Scan
Or when an index is used for the search:
select * from students
where class >= '3'
plan sort (students index (ix_stud_class))
order by name;
Advanced plan:
elect Expression -> Sort (record length: 136, key length: 56) -> Filter -> Table "STUDENTS" Access By ID -> Bitmap -> Index "IX_STUD_CLASS" Range Scan (lower bound: 1/1)
Notice that SORT
, unlike ORDER
, is outside the parentheses.This reflects the fact that the data rows are retrieved unordered and sorted afterward by the engine.
When selecting from a view, specify the view and the table involved.For instance, if you have a view FRESHMEN
that selects the first-year students:
select * from freshmen
plan (freshmen students natural);
Advanced plan:
Select Expression -> Table "STUDENTS" as "FRESHMEN" Full Scan
Or, for instance:
select * from freshmen
where id > 10
plan sort (freshmen students index (pk_students))
order by name desc;
Advanced plan:
Select Expression -> Sort (record length: 144, key length: 24) -> Filter -> Table "STUDENTS" as "FRESHMEN" Access By ID -> Bitmap -> Index "PK_STUDENTS" Range Scan (lower bound: 1/1)
Important
|
If a table or view has been aliased, it is the alias, not the original name, that must be used in the |