Plan optimization guidelines
Plan optimization guidelines are applied during the cost-based phase of optimization, where access methods, join methods, join order, and other details of the execution plan for the statement are determined.
Plan optimization guidelines need not specify all aspects of an execution plan. Unspecified aspects of the execution plan are determined by the optimizer in a cost-based fashion.
- accessRequest – An access request specifies an access method for satisfying a table reference in a statement.
- joinRequest – A join request specifies a method and sequence for performing a join operation. Join requests are composed of access or other join requests.
- grpbyRequest - A group by request specifies how a grouping operation is performed.
Access request optimization guidelines correspond to the data access methods of the optimizer, such as table scan, index scan, and list prefetch. Join request guidelines correspond to the join methods of the optimizer, such as nested-loop join, hash join, and merge join. Each access request and join request is represented by a corresponding access request element and join request element in the statement optimization guideline schema.
Group by request guidelines correspond to the grouping (GRPBY) operator of the optimizer. Each access, join or group by request is represented by a corresponding access, join or group by request element in the statement optimization guideline schema.
SQL statement:
select s.s_name, s.s_address, s.s_phone, s.s_comment
from "Samp".parts, "Samp".suppliers s, "Samp".partsupp ps
where p_partkey = ps.ps_partkey and
s.s_suppkey = ps.ps_suppkey and
p_size = 39 and
p_type = 'BRASS' and
s.s_nation in ('MOROCCO', 'SPAIN') and
ps.ps_supplycost = (select min(ps1.ps_supplycost)
from "Samp".partsupp ps1, "Samp".suppliers s1
where "Samp".parts.p_partkey = ps1.ps_partkey and
s1.s_suppkey = ps1.ps_suppkey and
s1.s_nation = s.s_nation)
order by s.s_name
Optimization guideline:
<OPTGUIDELINES>
<IXSCAN TABLE='S' INDEX='I_SUPPKEY'/>
</OPTGUIDELINES> <OPTGUIDELINES>
<IXSCAN TABLE='"Samp".PARTS'/>
</OPTGUIDELINES> <OPTGUIDELINES>
<LPREFETCH TABLE='S1' INDEX='I_SNATION'/>
</OPTGUIDELINES>SQL statement:
select s.s_name, s.s_address, s.s_phone, s.s_comment
from "Samp".parts, "Samp".suppliers s, "Samp".partsupp ps
where p_partkey = ps.ps_partkey
s.s_suppkey = ps.ps_suppkey and
p_size = 39 and
p_type = 'BRASS' and
s.s_nation in ('MOROCCO', 'SPAIN') and
ps.ps_supplycost = (select min(ps1.ps_supplycost)
from "Samp".partsupp ps1, "Samp".suppliers s1
where "Samp".parts.p_partkey = ps1.ps_partkey and
s1.s_suppkey = ps1.ps_suppkey and
s1.s_nation = s.s_nation)
order by s.s_name
optimize for 1 row
Optimization guidelines:
<OPTGUIDELINES>
<IXSCAN TABLE='S' INDEX='I_SNAME' FIRST='TRUE'/>
</OPTGUIDELINES> <OPTGUIDELINES>
<TBSCAN TABLE='S1'/>
<LPREFETCH TABLE='S' INDEX='I_SUPPKEY'/>
</OPTGUIDELINES> <OPTGUIDELINES>
<NLJOIN>
<IXSCAN TABLE='"Samp".Parts'/>
<IXSCAN TABLE="PS"/>
</NLJOIN>
</OPTGUIDELINES> <OPTGUIDELINES>
<HSJOIN>
<ACCESS TABLE='S1'/>
<IXSCAN TABLE='PS1'/>
</HSJOIN>
</OPTGUIDELINES> <OPTGUIDELINES>
<MSJOIN>
<NLJOIN>
<IXSCAN TABLE='"Samp".Parts'/>
<IXSCAN TABLE="PS"/>
</NLJOIN>
<IXSCAN TABLE='S'/>
</MSJOIN>
</OPTGUIDELINES>If a join request is to be valid, all access request elements that are nested either directly or indirectly inside of it must reference tables in the same FROM clause of the optimized statement.
Optimization guidelines for MQT matching
- NAME
- specifies the partial or fully qualified name of MQT to choose
- TYPE
- specifies a group of MQTs by their types. Possible values are:
- NORMAL: all non-replicated MQTs
- REPLICATED: all replicated MQTs
- ALL: all MQTs
<OPTGUIDELINES>
<MQTENFORCE NAME='SAMP.PARTSMQT'/>
<MQTENFORCE TYPE='REPLICATED'/>
</OPTGUIDELINES><MQTENFORCE NAME='SAMP.PARTSMQT' TYPE='REPLICATED'/>Only
PARTSMQT MQT is enforced