You can override the default behavior of the Derby query optimizer by including a --DERBY-PROPERTIES clause and an associated property as a comment within an SQL statement.
Because optimizer overrides are expressed as comments, they must be included at the end of a line. You can specify optimizer override properties for an entire FROM clause, for tables in the FROM clause, or for both.
FROM [ -- DERBY-PROPERTIES joinOrder = { FIXED | UNFIXED } ] ?????????????? TableExpression [,TableExpression]*
{table-Name | view-Name } ?????????????? [ [ AS ] correlation-Name ?????????????? ??[ (Simple-column-Name [ , Simple-column-Name ]* ) ] ] ?????????????? [ -- DERBY-PROPERTIES { constraint = constraint-Name | index = index-Name | joinStrategy = { NESTEDLOOP | HASH } } ]
The space between -- and DERBY-PROPERTIES is optional.
Typically, you will use the joinStrategy property only in conjunction with the joinOrder property. Specifying a join strategy without knowing the join order can result in less-than-optimal performance.
Valid values include HASH and NESTEDLOOP. The joinStrategy property can be used only within a TableExpression.
CREATE TABLE t1 (c1 int, c2 int, c3 int, CONSTRAINT cons1 PRIMARY KEY (c1, c2)) INSERT INTO t1 VALUES (1, 1, 1), (2, 2, 2), (3, 3, 3), (4, 4, 4) SELECT * FROM t1 --DERBY-PROPERTIES constraint=cons1 FOR UPDATE
CREATE TABLE t1 (c1 int, c2 int, c3 int, CONSTRAINT cons1 PRIMARY KEY (c1, c2)) INSERT INTO t1 VALUES (1, 1, 1), (2, 2, 2), (3, 3, 3), (4, 4, 4) CREATE INDEX t1_c1 ON t1(c1) SELECT * FROM t1 --DERBY-PROPERTIES index=t1_c1 WHERE c1=1
CREATE TABLE t1 (c1 int, c2 int, c3 int, CONSTRAINT cons1 PRIMARY KEY (c1, c2)) CREATE TABLE t2 (c1 int not null, c2 int not null, c3 int, CONSTRAINT cons2 UNIQUE (c1, c2)) INSERT INTO t1 VALUES (1, 1, 1), (2, 2, 2), (3, 3, 3), (4, 4, 4) INSERT INTO t2 VALUES (1, 1, 1), (2, 2, 2), (3, 3, 3), (4, 4, 4) SELECT * FROM --DERBY-PROPERTIES joinOrder=FIXED t1, t2 WHERE t1.c1=t2.c1
CREATE TABLE t1 (c1 int, c2 int, c3 int, CONSTRAINT cons1 PRIMARY KEY (c1, c2)) CREATE TABLE t2 (c1 int not null, c2 int not null, c3 int, CONSTRAINT cons2 UNIQUE (c1, c2)) INSERT INTO t1 VALUES (1, 1, 1), (2, 2, 2), (3, 3, 3), (4, 4, 4) INSERT INTO t2 VALUES (1, 1, 1), (2, 2, 2), (3, 3, 3), (4, 4, 4) SELECT * FROM --DERBY-PROPERTIES joinOrder=FIXED t1 a, t1 b --DERBY-PROPERTIES joinStrategy=NESTEDLOOP WHERE a.c1=b.c1