Pervasive logo

Prev SQL Engine Reference Next

Restriction Optimization


This section provides a detailed description of the primary techniques employed by the SRDE to make use of expressions in a restriction for optimization purposes. The types of optimizations performed by the SRDE are described below in order from the simplest to the most complex.

A clear understanding of optimization techniques used by the SRDE may aid you in structuring queries to achieve optimal performance from the SRDE. In addition, by understanding how the SRDE uses indexes to optimize queries, you can determine how to construct indexes that provide the best performance for a given set of typical uses.

For the sake of simplicity, the descriptions below initially address expressions that reference columns from only a single table. Optimizations making use of join conditions, in which predicates compare columns from two different tables, are described following the single table optimizations.

For definitions of the technical terms used in this chapter, see Terminology .

Single Predicate Optimization

The simplest form of Restriction optimization involves the use of a single Predicate. A predicate can be used for optimization if it meets all of the following conditions:

For example, suppose an index exists with the first segment on column c1. The following predicates can be used for optimization:

c1 = 1 
c1 IN (1,2) 
c1 > 1  

Past Behavior

Pervasive.SQL 2000i also supports single predicate optimization.

Closed Range Optimization

A Closed Range can be used for optimization if it satisfies all the requirements for Single Predicate Optimization.

For example, suppose an index exists with the first segment on column c1. The following closed range can be used for optimization:

c1 >= 1 AND c1 < 10 

Past Behavior

Pervasive.SQL 2000i also supports closed range optimization.

Modified Disjunct Optimization

A Modified Disjunct can be used for optimization if it satisfies all of the following conditions:

For example, suppose an index exists with the first segment on column c1. The following modified disjunct can be used for optimization:

c1 = 1 OR (c1 > 5 AND c1 < 10) OR c1 > 20 

The following modified disjunct cannot be used for this type of optimization because the same column is not referenced in all predicates and closed ranges:

c1 = 1 OR (c1 > 5 AND c1 < 10) OR c2 = 1 

Past Behavior

Pervasive.SQL 2000i does not support modified disjunct optimization.

Pervasive.SQL 2000i does support disjunct optimization, if the disjunct consists only of predicates (no closed ranges). Furthermore all of the predicates must contain the equal (=) comparison operation.

Conjunct Optimization

A Conjunct can be used for optimization if it satisfies all of the following conditions:

For example, suppose an index exists with the first three segments on columns c1, c2 and c3, in that order. The following conjuncts can be used for optimization:

c1 = 1 AND c2 = 1 AND c3 = 1 
c1 = 1 AND c2 = 1 AND c3 >= 1 
c1 = 1 AND c2 > 1 

The order of the predicates does not matter. For example, the following conjunct can be used for optimization:

c2 = 1 AND c3 = 1 AND c1 = 1 

The following conjunct cannot be used for optimization because the second segment of the index is skipped (there is no reference to column c2):

c1 = 1 AND c3 = 1 

In this case, the single predicate, c1 = 1, can still be used for optimization.

Past Behavior

Pervasive.SQL 2000i also supports conjunct optimization.

Disjunctive Normal Form Optimization

An expression in Disjunctive Normal Form (DNF) can be used for optimization if it satisfies all of the following conditions:

The SRDE does not convert restrictions that are originally in DNF into modified CNF, because it can optimize on DNF.

For example, suppose an index exists with the first three segments on columns c1, c2 and c3, in that order. The following expression in DNF can be used for optimization:

(c1 = 1 AND c2 = 1 AND c3 = 1) OR (c1 = 1 AND c2 = 1 AND c3 = 2) OR (c1 = 2 AND c2 = 2 AND c3 = 2) 

The following expression in DNF cannot be used for optimization because both conjuncts do not reference the same number of segments:

(c1 = 1 AND c2 = 1 AND c3 = 1) OR (c1 = 1 AND c2 = 2) 

Past Behavior

Pervasive.SQL 2000i also supports DNF optimization.

Modified Conjunctive Normal Form Optimization

An expression in Modified Conjunctive Normal Form (Modified CNF) can be used for optimization if it satisfies all of the following conditions:

Modified CNF optimization is similar to DNF optimization but allows combinations of predicates involving different comparison operations not supported by DNF optimization.

For example, suppose an index exists with the first three segments on columns c1, c2 and c3, in that order. The following expression in modified CNF can be used for optimization:

(c1 = 1 OR c1 = 2) AND (c2 = 1 OR (c2 > 2 AND c2 < 5)) AND (c3 > 1) 

It may be easier to understand how the SRDE uses this expression for optimization by looking at the equivalent expression in modified DNF:

(c1 = 1 AND c2 = 1 AND c3 > 1) OR (c1 = 1 AND (c2 > 2 AND c2 < 5) AND c3 > 1) OR (c1 = 2 AND c2 = 1 AND c3 > 1) OR (c1 = 2 AND (c2 > 2 AND c2 < 5) AND c3 > 1) 

Past Behavior

Pervasive.SQL 2000i does not support modified CNF optimization.

Closing Open Ended Ranges through Modified CNF Optimization

Two Modified Disjuncts can be combined to form one or more Closed Ranges if the following conditions are satisfied:

For example, suppose an index exists with the first segment on column c1. The following expression in modified CNF can be used for optimization:

(c1 = 1 OR c1 > 2) AND (c1 < 5 OR c1 = 10) 

It may be easier to understand how the SRDE uses this expression for optimization by looking at an equivalent expression which is simply a modified disjunct:

c1 = 1 OR (c1 > 2 AND c1 < 5) OR c1 = 10 

Past Behavior

Pervasive.SQL 2000i does not support this type of optimization.

Single Join Condition Optimization

The simplest form of optimization involving two tables makes use of a single Join Condition. Single join condition optimization is similar to Single Predicate Optimization. A join condition can be used for optimization if it satisfies the requirements for single predicate optimization. The table that will be optimized through the use of the join condition will be processed after the other table referenced in the join condition. The table optimized through the use of the join condition uses an optimization value retrieved from a row in the other table referenced in the join condition.

For example, suppose an index exists on table t1 with the first segment on column c1. The following join conditions can be used for optimization:

t1.c1 = t2.c1 
t1.c1 > t2.c2 

During optimization, a row is retrieved from table t2. From this row, the value of column c2 is used to optimize on table t1 according to the join condition.

If, instead of an index on t1.c1, there is an index on t2.c1, then t1.c1=t2.c1 could be used to optimize on table t2. In this case, table t1 would be processed first and the value for t1.c1 would be used to optimize on table t2 according to the join condition.

In the case that there is an index on t1.c1 as well as an index on t2.c1, the SRDE query optimizer examines the size of both tables as well as the characteristics of the two indexes and chooses the table to optimize that will provide the best overall query performance.

Past Behavior

Pervasive.SQL 2000i also supports single join condition optimization.

Conjunct with Join Conditions Optimization

A Conjunct that consists of a mixture of join conditions and other Predicates can be used for optimization if it satisfies all of the following conditions:

The table that will be optimized through the use of the conjunct will be processed after the other table referenced.

For example, suppose an index exists on table t1 with the first three segments on columns c1, c2 and c3, in that order. The following conjuncts can be used for optimization:

t1.c1 = t2.c1 AND t1.c2 = t2.c2 AND t1.c3 = t2.c3 
t1.c1 = t2.c1 AND t1.c2 > t2.c2 
t1.c1 = t2.c1 AND t1.c2 = 1 
t1.c1 = 1 AND t1.c2 = t2.c2 

Past Behavior

Pervasive.SQL 2000i also supports this type of optimization except that Pervasive.SQL 2000i has the additional requirements that the conjunct must contain only join conditions, no other predicates, and all the join conditions must contain the equal (=) comparison operation. Thus, to optimize the examples above, Pervasive.SQL 2000i would be able to use the entire first example, only the first join condition in the second example, only the join condition in the third example, and none of the fourth example.

Modified Conjunctive Normal Form with Join Conditions Optimization

An Expression in Modified Conjunctive Normal Form (Modified CNF) that contains join conditions can be used for optimization if it satisfies all the following conditions:

For example, suppose an index exists on table t1 with the first three segments on columns c1, c2 and c3, in that order. The following expressions in modified CNF can be used for optimization:

(t1.c1 = t2.c1) AND (t1.c2 = t2.c2 OR  
(t1.c2 > 2 AND t1.c2 < 5)) 
 
(t1.c1 = 1) AND (t1.c2 = t2.c2) AND  
(t1.c3 > 2 AND t1.c3 < 5) 

Past Behavior

Pervasive.SQL 2000i does not support this type of optimization.

Closing Join Condition Open Ended Ranges through Modified CNF Optimization

This type of optimization is exactly like Closing Open Ended Ranges through Modified CNF Optimization except that the range being closed may be a Join Condition.

For example, suppose an index exists on table t1 with the first two segments on columns c1 and c2, in that order. The following expressions in modified CNF can be used for optimization:

(t1.c1 > t2.c1) AND (t1.c1 < t2.c2 OR t1.c1 = 10) 
 
(t1.c1 = t2.c1) AND (t1.c2 > t2.c2) AND (t1.c2 < 10 OR t1.c2 = 100) 

Past Behavior

Pervasive.SQL 2000i does not support this type of optimization.

Multi-Index Modified Disjunct Optimization

A Modified Disjunct can be used for optimization through the use of more than one index if it satisfies all of the following conditions:

For example, suppose an index exists with the first segment on column c1 and another index exists with the first segment on column c2. The following modified disjunct can be used for optimization:

c1 = 1 OR (c1 > 5 AND c1 < 10) OR c2 = 1 

Past Behavior

Pervasive.SQL 2000i does not support this type of optimization.


Prev
Restriction Analysis
Contents
Up
Check for Revisions
Next
Push-Down Filters