!284 rewrite ROWNUM to LIMIT if possible
Merge pull request !284 from 周雄佳/master
This commit is contained in:
@ -108,7 +108,6 @@ extern RangeTblEntry* make_dummy_remote_rte(char* relname, Alias* alias);
|
||||
extern List* reassign_nodelist(RangeTblEntry* rte, List* ori_node_list);
|
||||
extern Node* preprocess_expression(PlannerInfo* root, Node* expr, int kind);
|
||||
|
||||
void preprocess_qual_conditions(PlannerInfo* root, Node* jtnode);
|
||||
static Plan* inheritance_planner(PlannerInfo* root);
|
||||
static Plan* grouping_planner(PlannerInfo* root, double tuple_fraction);
|
||||
static void preprocess_rowmarks(PlannerInfo* root);
|
||||
@ -1203,7 +1202,10 @@ Plan* subquery_planner(PlannerGlobal* glob, Query* parse, PlannerInfo* parent_ro
|
||||
if (parse->commandType == CMD_SELECT && checkSelectStmtForPlanTable(parse->rtable)) {
|
||||
OnlySelectFromPlanTable = true;
|
||||
}
|
||||
|
||||
|
||||
/* Change ROWNUM to LIMIT if possible */
|
||||
preprocess_rownum(root, parse);
|
||||
DEBUG_QRW("After preprocess rownum");
|
||||
/*
|
||||
* Check to see if any subqueries in the jointree can be merged into this
|
||||
* query.
|
||||
@ -1364,7 +1366,9 @@ Plan* subquery_planner(PlannerGlobal* glob, Query* parse, PlannerInfo* parent_ro
|
||||
}
|
||||
|
||||
parse->limitOffset = preprocess_expression(root, parse->limitOffset, EXPRKIND_LIMIT);
|
||||
parse->limitCount = preprocess_expression(root, parse->limitCount, EXPRKIND_LIMIT);
|
||||
if (parse->limitCount != NULL && !IsA(parse->limitCount, Const)) {
|
||||
parse->limitCount = preprocess_expression(root, parse->limitCount, EXPRKIND_LIMIT);
|
||||
}
|
||||
|
||||
foreach (l, parse->mergeActionList) {
|
||||
MergeAction* action = (MergeAction*)lfirst(l);
|
||||
|
@ -46,6 +46,9 @@
|
||||
#include "parser/parse_oper.h"
|
||||
#include "utils/lsyscache.h"
|
||||
#include "access/transam.h"
|
||||
#include "catalog/pg_operator.h"
|
||||
#include "nodes/pg_list.h"
|
||||
#include "optimizer/planner.h"
|
||||
|
||||
typedef struct pullup_replace_vars_context {
|
||||
PlannerInfo* root;
|
||||
@ -88,8 +91,17 @@ static void fix_append_rel_relids(List* append_rel_list, int varno, Relids subre
|
||||
static Node* find_jointree_node_for_rel(Node* jtnode, int relid);
|
||||
static Node* deleteRelatedNullTest(Node* node, PlannerInfo* root);
|
||||
static Node* reduce_inequality_fulljoins_jointree_recurse(PlannerInfo* root, Node* jtnode);
|
||||
|
||||
static bool find_rownum_in_quals(PlannerInfo *root);
|
||||
static bool process_rownum_opexpr(Query *parse, OpExpr *expr, bool isOrExpr);
|
||||
static Node *process_rownum_boolexpr(Query *parse, BoolExpr *quals, BoolExprType type);
|
||||
static bool process_rownum_opexpr_lessthan(Query *parse, Node *qual, int64 var, bool isOrExpr);
|
||||
static bool process_rownum_opexpr_lessthanEqual(Query *parse, Node *qual, int64 var, bool isOrExpr);
|
||||
static bool process_rownum_opexpr_Equal(Query *parse, Node *qual, int64 var, bool isOrExpr);
|
||||
static bool process_rownum_opexpr_greaterthan(Query *parse, Node *qual, int64 var, bool isOrExpr);
|
||||
static bool process_rownum_opexpr_greaterEqualthan(Query *parse, Node *qual, int64 var, bool isOrExpr);
|
||||
static bool process_rownum_opexpr_notEqual(Query *parse, Node *qual, int64 var, bool isOrExpr);
|
||||
static int64 get_constvalue_from_opexpr(OpExpr *expr);
|
||||
|
||||
|
||||
/*
|
||||
* pull_up_sublinks
|
||||
@ -1377,6 +1389,9 @@ static bool is_simple_subquery(Query* subquery)
|
||||
* that case the locking was originally declared in the upper query
|
||||
* anyway.
|
||||
*/
|
||||
if (verify_rownum_optimization_possibility(subquery)) {
|
||||
return false;
|
||||
}
|
||||
if (subquery->hasAggs || subquery->hasWindowFuncs || subquery->groupClause || subquery->groupingSets ||
|
||||
subquery->havingQual || subquery->sortClause || subquery->distinctClause || subquery->limitOffset ||
|
||||
subquery->limitCount || subquery->hasForUpdate || subquery->cteList)
|
||||
@ -1443,6 +1458,9 @@ static bool is_simple_union_all(Query* subquery)
|
||||
AssertEreport(
|
||||
IsA(topop, SetOperationStmt), MOD_OPT_REWRITE, "subquery's setOperations mismatch in is_simple_union_all");
|
||||
|
||||
if (verify_rownum_optimization_possibility(subquery)) {
|
||||
return false;
|
||||
}
|
||||
/* Can't handle ORDER BY, LIMIT/OFFSET, locking, or WITH */
|
||||
if (subquery->sortClause || subquery->limitOffset || subquery->limitCount || subquery->rowMarks ||
|
||||
subquery->cteList)
|
||||
@ -2931,3 +2949,259 @@ static bool find_rownum_in_quals(PlannerInfo *root)
|
||||
|
||||
return hasRownum;
|
||||
}
|
||||
|
||||
/*
|
||||
* preprocess_rownum
|
||||
* change ROWNUM to LIMIT in parse tree if possible
|
||||
*/
|
||||
void preprocess_rownum(PlannerInfo *root, Query *parse)
|
||||
{
|
||||
if (!verify_rownum_optimization_possibility(parse)) {
|
||||
return;
|
||||
}
|
||||
if (parse->limitCount != NULL && !IsA(parse->limitCount, Const)) {
|
||||
parse->limitCount = eval_const_expressions(root, parse->limitCount);
|
||||
}
|
||||
Node *node = (Node *)parse->jointree->quals;
|
||||
if (node == NULL) {
|
||||
return;
|
||||
}
|
||||
|
||||
switch (nodeTag(node)) {
|
||||
case T_OpExpr: {
|
||||
bool canBeOptimized = process_rownum_opexpr(parse, (OpExpr *)node, false);
|
||||
if (canBeOptimized) {
|
||||
free_quals(parse);
|
||||
}
|
||||
break;
|
||||
}
|
||||
case T_BoolExpr: {
|
||||
parse->jointree->quals = process_rownum_boolexpr(parse, (BoolExpr *)node, ((BoolExpr *)node)->boolop);
|
||||
break;
|
||||
}
|
||||
default: {
|
||||
break;
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
Node *process_rownum_boolexpr(Query *parse, BoolExpr *quals, BoolExprType type)
|
||||
{
|
||||
ListCell *qualCell = list_head(quals->args);
|
||||
ListCell *next = NULL;
|
||||
ListCell *prev = NULL;
|
||||
|
||||
while (qualCell != NULL) {
|
||||
Node *clause = (Node *)lfirst(qualCell);
|
||||
next = lnext(qualCell);
|
||||
|
||||
if (!IsA(clause, OpExpr)) {
|
||||
prev = qualCell;
|
||||
qualCell = next;
|
||||
continue;
|
||||
}
|
||||
|
||||
OpExpr *expr = (OpExpr *)clause;
|
||||
bool canBeOptimized = false;
|
||||
if (type == AND_EXPR) {
|
||||
canBeOptimized = process_rownum_opexpr(parse, expr, false);
|
||||
} else {
|
||||
canBeOptimized = process_rownum_opexpr(parse, expr, true);
|
||||
}
|
||||
|
||||
if (parse->jointree->quals == NULL) {
|
||||
return NULL;
|
||||
}
|
||||
if (canBeOptimized) {
|
||||
quals->args = list_delete_cell(quals->args, qualCell, prev);
|
||||
qualCell = next;
|
||||
continue;
|
||||
}
|
||||
prev = qualCell;
|
||||
qualCell = next;
|
||||
}
|
||||
return (Node *)quals;
|
||||
}
|
||||
|
||||
static bool process_rownum_opexpr(Query *parse, OpExpr *expr, bool isOrExpr)
|
||||
{
|
||||
if (!contain_optimizable_rownum_opexpr(expr)) {
|
||||
return false;
|
||||
}
|
||||
int64 var = get_constvalue_from_opexpr(expr);
|
||||
Node *valueNode = (Node *)llast(expr->args);
|
||||
if (expr->opno == INT84LTOID) {
|
||||
/* operator '<' */
|
||||
return process_rownum_opexpr_lessthan(parse, valueNode, var, isOrExpr);
|
||||
} else if (expr->opno == INT84LEOID) {
|
||||
/* operator '<=' */
|
||||
return process_rownum_opexpr_lessthanEqual(parse, valueNode, var, isOrExpr);
|
||||
} else if (expr->opno == INT84EQOID) {
|
||||
/* operator '=' */
|
||||
return process_rownum_opexpr_Equal(parse, valueNode, var, isOrExpr);
|
||||
} else if (expr->opno == INT84GTOID) {
|
||||
/* operator '>' */
|
||||
return process_rownum_opexpr_greaterthan(parse, valueNode, var, isOrExpr);
|
||||
} else if (expr->opno == INT84GEOID) {
|
||||
/* operator '>=' */
|
||||
return process_rownum_opexpr_greaterEqualthan(parse, valueNode, var, isOrExpr);
|
||||
} else if (expr->opno == INT84NEOID) {
|
||||
/* operator '!=' */
|
||||
return process_rownum_opexpr_notEqual(parse, valueNode, var, isOrExpr);
|
||||
} else {
|
||||
return false;
|
||||
}
|
||||
}
|
||||
|
||||
/* process operator '<' in rownum expr like {rownum < 5}
|
||||
* if it can be rewrited to LIMIT, return TRUE
|
||||
*/
|
||||
static bool process_rownum_opexpr_lessthan(Query *parse, Node *valueNode, int64 var, bool isOrExpr)
|
||||
{
|
||||
if (isOrExpr == false) {
|
||||
if (var > 1) {
|
||||
rewrite_rownum_to_limit(parse, valueNode, var - 1);
|
||||
} else {
|
||||
rewrite_rownum_to_limit(parse, valueNode, 0);
|
||||
free_quals(parse);
|
||||
return false;
|
||||
}
|
||||
} else {
|
||||
if (var > 1) {
|
||||
return false;
|
||||
}
|
||||
}
|
||||
|
||||
return true;
|
||||
}
|
||||
|
||||
/* process operator '<=' in rownum expr like {rownum <= 5}
|
||||
* if it can be rewrited to LIMIT, return TRUE
|
||||
*/
|
||||
static bool process_rownum_opexpr_lessthanEqual(Query *parse, Node *valueNode, int64 var, bool isOrExpr)
|
||||
{
|
||||
if (isOrExpr == false) {
|
||||
if (var >= 1) {
|
||||
rewrite_rownum_to_limit(parse, valueNode, var);
|
||||
} else {
|
||||
rewrite_rownum_to_limit(parse, valueNode, 0);
|
||||
free_quals(parse);
|
||||
return false;
|
||||
}
|
||||
} else {
|
||||
if (var >= 1) {
|
||||
return false;
|
||||
}
|
||||
}
|
||||
|
||||
return true;
|
||||
}
|
||||
|
||||
/* process operator '=' in rownum expr like {rownum = 5}
|
||||
* if it can be rewrited to LIMIT, return TRUE
|
||||
*/
|
||||
static bool process_rownum_opexpr_Equal(Query *parse, Node *valueNode, int64 var, bool isOrExpr)
|
||||
{
|
||||
if (isOrExpr == false) {
|
||||
if (var == 1) {
|
||||
rewrite_rownum_to_limit(parse, valueNode, 1);
|
||||
} else {
|
||||
rewrite_rownum_to_limit(parse, valueNode, 0);
|
||||
free_quals(parse);
|
||||
return false;
|
||||
}
|
||||
} else {
|
||||
if (var > 0) {
|
||||
return false;
|
||||
;
|
||||
}
|
||||
}
|
||||
|
||||
return true;
|
||||
}
|
||||
|
||||
/* process operator '>' in rownum expr like {rownum > 5}
|
||||
* if it can be rewrited to LIMIT, return TRUE
|
||||
*/
|
||||
static bool process_rownum_opexpr_greaterthan(Query *parse, Node *valueNode, int64 var, bool isOrExpr)
|
||||
{
|
||||
if (isOrExpr == false) {
|
||||
if (var >= 1) {
|
||||
rewrite_rownum_to_limit(parse, valueNode, 0);
|
||||
free_quals(parse);
|
||||
return false;
|
||||
}
|
||||
} else {
|
||||
if (var < 1) {
|
||||
free_quals(parse);
|
||||
}
|
||||
return false;
|
||||
}
|
||||
|
||||
return true;
|
||||
}
|
||||
|
||||
/* process operator '>=' in rownum expr like {rownum >= 5}
|
||||
* if it can be rewrited to LIMIT, return TRUE
|
||||
*/
|
||||
static bool process_rownum_opexpr_greaterEqualthan(Query *parse, Node *valueNode, int64 var, bool isOrExpr)
|
||||
{
|
||||
if (isOrExpr == false) {
|
||||
if (var > 1) {
|
||||
rewrite_rownum_to_limit(parse, valueNode, 0);
|
||||
free_quals(parse);
|
||||
return false;
|
||||
}
|
||||
} else {
|
||||
if (var <= 1) {
|
||||
free_quals(parse);
|
||||
}
|
||||
return false;
|
||||
}
|
||||
|
||||
return true;
|
||||
}
|
||||
|
||||
/* process operator '!=' in rownum expr like {rownum != 5}
|
||||
* if it can be rewrited to LIMIT, return TRUE
|
||||
*/
|
||||
static bool process_rownum_opexpr_notEqual(Query *parse, Node *valueNode, int64 var, bool isOrExpr)
|
||||
{
|
||||
if (isOrExpr == false) {
|
||||
if (var == 1) {
|
||||
rewrite_rownum_to_limit(parse, valueNode, 0);
|
||||
free_quals(parse);
|
||||
return false;
|
||||
} else if (var > 1) {
|
||||
rewrite_rownum_to_limit(parse, valueNode, var - 1);
|
||||
} else {
|
||||
/* nothing to do here */
|
||||
}
|
||||
} else {
|
||||
if (var < 1) {
|
||||
free_quals(parse);
|
||||
}
|
||||
return false;
|
||||
}
|
||||
|
||||
return true;
|
||||
}
|
||||
|
||||
/* extract const value from OpExpr like {rownum < Const} */
|
||||
static int64 get_constvalue_from_opexpr(OpExpr *expr)
|
||||
{
|
||||
Node *valueNode = (Node *)llast(expr->args);
|
||||
Oid type = ((Const *)valueNode)->consttype;
|
||||
Datum value = ((Const *)valueNode)->constvalue;
|
||||
int64 result;
|
||||
if (type == INT8OID) {
|
||||
result = DatumGetInt64(value);
|
||||
} else {
|
||||
result = (int64)DatumGetInt32(value);
|
||||
((Const *)valueNode)->consttype = INT8OID;
|
||||
((Const *)valueNode)->constlen = sizeof(int64);
|
||||
((Const *)valueNode)->constbyval = FLOAT8PASSBYVAL;
|
||||
}
|
||||
|
||||
return result;
|
||||
}
|
@ -70,6 +70,8 @@ extern bool plan_cluster_use_sort(Oid tableOid, Oid indexOid);
|
||||
|
||||
extern bool ContainRecursiveUnionSubplan(PlannedStmt* pstmt);
|
||||
|
||||
extern void preprocess_qual_conditions(PlannerInfo* root, Node* jtnode);
|
||||
|
||||
typedef enum {
|
||||
/*
|
||||
* Disable "inlist2join" rewrite optimization
|
||||
|
@ -19,6 +19,8 @@
|
||||
#include "nodes/relation.h"
|
||||
|
||||
#include "utils/guc.h"
|
||||
#include "catalog/pg_operator.h"
|
||||
#include "optimizer/clauses.h"
|
||||
|
||||
/*
|
||||
* prototypes for prepjointree.c
|
||||
@ -26,51 +28,108 @@
|
||||
extern void pull_up_sublinks(PlannerInfo* root);
|
||||
extern void substitute_ctes_with_subqueries(PlannerInfo* root, Query* parse, bool under_recursive_tree);
|
||||
extern void inline_set_returning_functions(PlannerInfo* root);
|
||||
extern Node* pull_up_subqueries(
|
||||
PlannerInfo* root, Node* jtnode, JoinExpr* lowest_outer_join, AppendRelInfo* containing_appendrel);
|
||||
extern void flatten_simple_union_all(PlannerInfo* root);
|
||||
extern void removeNotNullTest(PlannerInfo* root);
|
||||
extern void reduce_outer_joins(PlannerInfo* root);
|
||||
extern void reduce_inequality_fulljoins(PlannerInfo* root);
|
||||
extern Relids get_relids_in_jointree(Node* jtnode, bool include_joins);
|
||||
extern Relids get_relids_for_join(PlannerInfo* root, int joinrelid);
|
||||
extern void pull_up_subquery_hint(PlannerInfo* root, Query* parse, HintState* hint_state);
|
||||
extern Node *pull_up_subqueries(PlannerInfo *root, Node *jtnode, JoinExpr *lowest_outer_join,
|
||||
AppendRelInfo *containing_appendrel);
|
||||
extern void flatten_simple_union_all(PlannerInfo *root);
|
||||
extern void removeNotNullTest(PlannerInfo *root);
|
||||
extern void reduce_outer_joins(PlannerInfo *root);
|
||||
extern void reduce_inequality_fulljoins(PlannerInfo *root);
|
||||
extern Relids get_relids_in_jointree(Node *jtnode, bool include_joins);
|
||||
extern Relids get_relids_for_join(PlannerInfo *root, int joinrelid);
|
||||
extern void pull_up_subquery_hint(PlannerInfo *root, Query *parse, HintState *hint_state);
|
||||
extern void preprocess_rownum(PlannerInfo *root, Query *parse);
|
||||
|
||||
/*
|
||||
* prototypes for prepnonjointree.cpp
|
||||
*/
|
||||
extern bool get_real_rte_varno_attno(
|
||||
Query* parse, Index* varno, AttrNumber* varattno, const Index targetVarno = InvalidOid);
|
||||
extern bool is_join_inner_side(
|
||||
const Node* fromNode, const Index targetRTEIndex, const bool isParentInnerSide, bool* isFound);
|
||||
extern Query* lazyagg_main(Query* parse);
|
||||
extern void reduce_orderby(Query* query, bool reduce);
|
||||
extern bool get_real_rte_varno_attno(Query *parse, Index *varno, AttrNumber *varattno,
|
||||
const Index targetVarno = InvalidOid);
|
||||
extern bool is_join_inner_side(const Node *fromNode, const Index targetRTEIndex, const bool isParentInnerSide,
|
||||
bool *isFound);
|
||||
extern Query *lazyagg_main(Query *parse);
|
||||
extern void reduce_orderby(Query *query, bool reduce);
|
||||
|
||||
extern Node* get_real_rte_varno_attno_or_node(Query* parse, Index* varno, AttrNumber* varattno);
|
||||
extern Node *get_real_rte_varno_attno_or_node(Query *parse, Index *varno, AttrNumber *varattno);
|
||||
|
||||
/*
|
||||
* prototypes for prepqual.c
|
||||
*/
|
||||
extern Node* negate_clause(Node* node);
|
||||
extern Expr* canonicalize_qual(Expr* qual);
|
||||
extern Node *negate_clause(Node *node);
|
||||
extern Expr *canonicalize_qual(Expr *qual);
|
||||
|
||||
/*
|
||||
* prototypes for preptlist.c
|
||||
*/
|
||||
extern List* preprocess_targetlist(PlannerInfo* root, List* tlist);
|
||||
extern List* preprocess_upsert_targetlist(List* tlist, int result_relation, List* range_table);
|
||||
extern PlanRowMark* get_plan_rowmark(List* rowmarks, Index rtindex);
|
||||
extern List *preprocess_targetlist(PlannerInfo *root, List *tlist);
|
||||
extern List *preprocess_upsert_targetlist(List *tlist, int result_relation, List *range_table);
|
||||
extern PlanRowMark *get_plan_rowmark(List *rowmarks, Index rtindex);
|
||||
|
||||
/*
|
||||
* prototypes for prepunion.c
|
||||
*/
|
||||
extern Plan* plan_set_operations(PlannerInfo* root, double tuple_fraction, List** sortClauses);
|
||||
extern Plan *plan_set_operations(PlannerInfo *root, double tuple_fraction, List **sortClauses);
|
||||
|
||||
extern void expand_inherited_tables(PlannerInfo* root);
|
||||
extern void make_inh_translation_list(
|
||||
Relation oldrelation, Relation newrelation, Index newvarno, List** translated_vars);
|
||||
extern Bitmapset* translate_col_privs(const Bitmapset* parent_privs, List* translated_vars);
|
||||
extern void expand_inherited_tables(PlannerInfo *root);
|
||||
extern void make_inh_translation_list(Relation oldrelation, Relation newrelation, Index newvarno,
|
||||
List **translated_vars);
|
||||
extern Bitmapset *translate_col_privs(const Bitmapset *parent_privs, List *translated_vars);
|
||||
|
||||
extern Node *adjust_appendrel_attrs(PlannerInfo *root, Node *node, AppendRelInfo *appinfo);
|
||||
|
||||
inline void free_quals(Query *parse)
|
||||
{
|
||||
pfree(parse->jointree->quals);
|
||||
parse->jointree->quals = NULL;
|
||||
}
|
||||
|
||||
/* judge if it is possible to optimize rownum */
|
||||
inline bool verify_rownum_optimization_possibility(Query *parse)
|
||||
{
|
||||
if (parse == NULL) {
|
||||
return false;
|
||||
}
|
||||
|
||||
if ((parse->commandType != CMD_SELECT) && (parse->commandType != CMD_INSERT) &&
|
||||
(parse->commandType != CMD_UPDATE) && (parse->commandType != CMD_DELETE)) {
|
||||
return false;
|
||||
}
|
||||
|
||||
if (!IsA((Node *)parse->jointree, FromExpr)) {
|
||||
return false;
|
||||
}
|
||||
|
||||
if (!contain_rownum_walker(((FromExpr *)parse->jointree)->quals, NULL)) {
|
||||
return false;
|
||||
}
|
||||
|
||||
return true;
|
||||
}
|
||||
|
||||
inline bool contain_optimizable_rownum_opexpr(OpExpr *expr)
|
||||
{
|
||||
if (!IsA((Node *)linitial(expr->args), Rownum))
|
||||
return false;
|
||||
|
||||
if (!IsA((Node *)llast(expr->args), Const))
|
||||
return false;
|
||||
|
||||
if (((Const *)llast(expr->args))->consttype != INT8OID && ((Const *)llast(expr->args))->consttype != INT4OID) {
|
||||
return false;
|
||||
}
|
||||
|
||||
return true;
|
||||
}
|
||||
|
||||
inline void rewrite_rownum_to_limit(Query *parse, Node *valueNode, int num)
|
||||
{
|
||||
((Const *)valueNode)->constvalue = num;
|
||||
if (parse->limitCount != NULL) {
|
||||
Const *Orin = (Const *)parse->limitCount;
|
||||
parse->limitCount = (Orin->constvalue < ((Const *)valueNode)->constvalue) ? (Node *)Orin : valueNode;
|
||||
} else {
|
||||
parse->limitCount = valueNode;
|
||||
}
|
||||
}
|
||||
|
||||
extern Node* adjust_appendrel_attrs(PlannerInfo* root, Node* node, AppendRelInfo* appinfo);
|
||||
|
||||
#endif /* PREP_H */
|
||||
|
File diff suppressed because it is too large
Load Diff
@ -182,3 +182,240 @@ insert into bbbb values (0, 1);
|
||||
select (select a1.smgwname from aaaa a1 where a1.seid = ( select a2.seid from aaaa a2 where a2.igmgwidx = b.imgwindex and a2.imsflag = b.imsflag and rownum <=1)) from bbbb b;
|
||||
drop table aaaa;
|
||||
drop table bbbb;
|
||||
|
||||
--test query plan after optimizing
|
||||
create table student(id int, stuname varchar(10) );
|
||||
insert into student values(1, 'stu1');
|
||||
insert into student values(2, 'stu2');
|
||||
insert into student values(3, 'stu3');
|
||||
insert into student values(4, 'stu4');
|
||||
insert into student values(5, 'stu5');
|
||||
insert into student values(6, 'stu6');
|
||||
insert into student values(7, 'stu7');
|
||||
insert into student values(8, 'stu8');
|
||||
insert into student values(9, 'stu9');
|
||||
insert into student values(10, 'stu10');
|
||||
|
||||
create table test(id int, testchar varchar(10));
|
||||
insert into test values(1, 'test1');
|
||||
insert into test values(2, 'test2');
|
||||
insert into test values(3, 'test3');
|
||||
insert into test values(4, 'test4');
|
||||
insert into test values(5, 'test5');
|
||||
insert into test values(6, 'test6');
|
||||
insert into test values(7, 'test7');
|
||||
insert into test values(8, 'test8');
|
||||
insert into test values(9, 'test9');
|
||||
insert into test values(10, 'test10');
|
||||
|
||||
-- operator '<' (with 'and')
|
||||
-- n > 1
|
||||
explain select * from student where rownum < 5;
|
||||
explain select * from student where rownum < 5 and id > 5;
|
||||
explain select * from student where rownum < 5 and id > 5 and id < 9;
|
||||
explain select * from student where rownum < 5 and rownum < 6;
|
||||
explain select * from student where rownum < 5 and rownum < 6 and rownum < 9;
|
||||
explain select * from student where rownum < 5 and rownum < 6 and rownum < 9 and rownum < 12;
|
||||
|
||||
-- n <= 1
|
||||
explain select * from student where rownum < 1;
|
||||
explain select * from student where rownum < -5;
|
||||
explain select * from student where rownum < -5 and id > 5;
|
||||
explain select * from student where rownum < -5 and id > 5 and id < 9;
|
||||
explain select * from student where rownum < -5 and rownum < 6;
|
||||
explain select * from student where rownum < -5 and rownum < 6 and rownum < 9;
|
||||
explain select * from student where rownum < -5 and rownum < 6 and rownum < 9 and rownum < 12;
|
||||
|
||||
-- operator '<=' (with 'and')
|
||||
-- n >= 1
|
||||
explain select * from student where rownum <= 1;
|
||||
explain select * from student where rownum <= 5;
|
||||
explain select * from student where rownum <= 5 and id > 5;
|
||||
explain select * from student where rownum <= 5 and id > 5 and id < 9;
|
||||
explain select * from student where rownum <= 5 and rownum < 6;
|
||||
explain select * from student where rownum <= 5 and rownum < 6 and rownum < 9;
|
||||
explain select * from student where rownum <= 5 and rownum < 6 and rownum < 9 and rownum < 12;
|
||||
|
||||
-- n < 1
|
||||
explain select * from student where rownum <= -5;
|
||||
explain select * from student where rownum <= -5 and id > 5;
|
||||
explain select * from student where rownum <= -5 and id > 5 and id < 9;
|
||||
explain select * from student where rownum <= -5 and rownum < 6;
|
||||
explain select * from student where rownum <= -5 and rownum < 6 and rownum < 9;
|
||||
explain select * from student where rownum <= -5 and rownum < 6 and rownum < 9 and rownum < 12;
|
||||
|
||||
|
||||
-- operator '=' (with 'and')
|
||||
-- n = 1
|
||||
explain select * from student where rownum = 1;
|
||||
explain select * from student where rownum = 1 and id > 5;
|
||||
explain select * from student where rownum = 1 and rownum = 2 and id > 5;
|
||||
|
||||
-- n != 1
|
||||
explain select * from student where rownum = 2;
|
||||
explain select * from student where rownum = 2 and id > 5;
|
||||
|
||||
-- operator '!=' (with 'and')
|
||||
-- n = 1
|
||||
explain select * from student where rownum != 1;
|
||||
explain select * from student where rownum != 1 and id > 5;
|
||||
explain select * from student where rownum != 1 and rownum != 2 and id > 5;
|
||||
|
||||
-- n > 1
|
||||
explain select * from student where rownum != 5;
|
||||
explain select * from student where rownum != 5 and id > 5;
|
||||
explain select * from student where rownum != 5 and rownum != 8 and id > 5;
|
||||
|
||||
-- n < 1
|
||||
explain select * from student where rownum != -5;
|
||||
explain select * from student where rownum != -5 and id > 5;
|
||||
explain select * from student where rownum != -5 and rownum != -8 and id > 5;
|
||||
|
||||
-- operator '>' (with 'and')
|
||||
-- n >= 1
|
||||
explain select * from student where rownum > 1;
|
||||
explain select * from student where rownum > 5;
|
||||
explain select * from student where rownum > 5 and id > 5;
|
||||
explain select * from student where rownum > 5 and id > 5 and id < 9;
|
||||
explain select * from student where rownum > 5 and rownum > 6;
|
||||
explain select * from student where rownum > 5 and rownum > 6 and rownum > 9;
|
||||
explain select * from student where rownum > 5 and rownum < 6 and rownum < 9 and rownum < 12;
|
||||
|
||||
--n < 1
|
||||
explain select * from student where rownum > -5;
|
||||
explain select * from student where rownum > -5 and id > 5;
|
||||
explain select * from student where rownum > -5 and id > 5 and id < 9;
|
||||
explain select * from student where rownum > -5 and rownum > 6;
|
||||
explain select * from student where rownum > -5 and rownum > 6 and rownum < 9;
|
||||
explain select * from student where rownum > -5 and rownum > 6 and rownum < 9 and rownum < 12;
|
||||
|
||||
-- operator '>=' (with 'and')
|
||||
-- n > 1
|
||||
explain select * from student where rownum >= 5;
|
||||
explain select * from student where rownum >= 5 and id > 5;
|
||||
explain select * from student where rownum >= 5 and id > 5 and id < 9;
|
||||
explain select * from student where rownum >= 5 and rownum > 6;
|
||||
explain select * from student where rownum >= 5 and rownum > 6 and rownum > 9;
|
||||
explain select * from student where rownum >= 5 and rownum < 6 and rownum < 9 and rownum < 12;
|
||||
|
||||
-- n <= 1
|
||||
explain select * from student where rownum >= 1;
|
||||
explain select * from student where rownum >= -5;
|
||||
explain select * from student where rownum >= -5 and id > 5;
|
||||
explain select * from student where rownum >= -5 and id > 5 and id < 9;
|
||||
explain select * from student where rownum >= -5 and rownum > 6;
|
||||
explain select * from student where rownum >= -5 and rownum > 6 and rownum < 9;
|
||||
explain select * from student where rownum >= -5 and rownum > 6 and rownum < 9 and rownum < 12;
|
||||
|
||||
-- operator '<' with 'or'
|
||||
-- n > 1
|
||||
-- can not be optimized
|
||||
explain select * from student where rownum < 5 or id > 5;
|
||||
|
||||
-- n <= 1
|
||||
explain select * from student where rownum < -5;
|
||||
explain select * from student where rownum < -5 or id > 5;
|
||||
explain select * from student where rownum < -5 or id > 5 or id < 9;
|
||||
|
||||
-- operator '<=' with 'or'
|
||||
-- n >= 1
|
||||
-- can not be optimized
|
||||
explain select * from student where rownum <= 5 or id > 5;
|
||||
|
||||
-- n < 1
|
||||
explain select * from student where rownum <= -5;
|
||||
explain select * from student where rownum <= -5 or id > 5;
|
||||
explain select * from student where rownum <= -5 or id > 5 or id < 9;
|
||||
|
||||
-- operator '=' with 'or'
|
||||
-- n > 0
|
||||
-- can not be optimized
|
||||
explain select * from student where rownum = 5 or id > 5;
|
||||
|
||||
-- n <= 0
|
||||
explain select * from student where rownum = 0 or id > 5;
|
||||
explain select * from student where rownum = -1 or id > 5;
|
||||
|
||||
-- operator '!=' with 'or'
|
||||
-- n >= 1
|
||||
-- can not be optimized
|
||||
explain select * from student where rownum != 6 or id > 5;
|
||||
|
||||
-- n<1
|
||||
explain select * from student where rownum != 0 or id > 5;
|
||||
|
||||
-- operator '>' with 'or'
|
||||
-- n >= 1
|
||||
-- can not be optimized
|
||||
explain select * from student where rownum > 5 or id > 5;
|
||||
|
||||
-- n < 1
|
||||
explain select * from student where rownum > -5;
|
||||
explain select * from student where rownum > -5 or id > 5;
|
||||
explain select * from student where rownum > -5 or id > 5 or id < 9;
|
||||
-- operator '>=' with 'or'
|
||||
-- n > 1
|
||||
-- can not be optimized
|
||||
explain select * from student where rownum >= 5 or id > 5;
|
||||
|
||||
-- n <= 1
|
||||
explain select * from student where rownum >= -5;
|
||||
explain select * from student where rownum >= -5 or id > 5;
|
||||
explain select * from student where rownum >= -5 or id > 5 or id < 9;
|
||||
|
||||
-- limit
|
||||
explain select * from student where rownum < 5 limit 3;
|
||||
explain select * from student where rownum < 3 limit 5;
|
||||
explain select * from student where rownum <= 5 limit 3;
|
||||
explain select * from student where rownum <= 3 limit 5;
|
||||
|
||||
-- subqueries
|
||||
explain select * from (select * from student where rownum < 5);
|
||||
explain select * from (select * from student where rownum < 5) where rownum < 9;
|
||||
explain select * from (select * from student where rownum < 5 and id < 7);
|
||||
explain select * from (select * from student where rownum < 3 and id < 10) where rownum < 5;
|
||||
explain select * from (select * from student where rownum < 3 and id < 10) where rownum < 2 and stuname = 'stu1';
|
||||
|
||||
--sublink
|
||||
explain select * from student where id in (select id from test where rownum < 4);
|
||||
explain select * from student where id in (select id from test where rownum < 4) and rownum < 6;
|
||||
explain select * from student where id in (select id from test where rownum < 4) and stuname in (select stuname from student where rownum < 6);
|
||||
explain select * from student where id in (select id from test where rownum < 4 and id < 7);
|
||||
explain select * from student where id in (select id from test where rownum < 4) and rownum < 6 and id > 3;
|
||||
|
||||
-- insert
|
||||
explain insert into test select * from student where rownum < 5;
|
||||
explain insert into test select * from student where rownum < 5 and id > 3;
|
||||
|
||||
-- between
|
||||
explain select * from student where rownum between 1 and 5;
|
||||
explain select * from student where rownum between 2 and 8;
|
||||
explain select * from student where rownum between -5 and 8;
|
||||
explain select * from student where rownum between -5 and -2;
|
||||
|
||||
--update
|
||||
explain update student set id = 5 where rownum < 3;
|
||||
explain update student set id = 5 where rownum < 3 and rownum < 5;
|
||||
explain update student set id = 5 where rownum > 3;
|
||||
|
||||
--delete
|
||||
explain delete from student where rownum < 3;
|
||||
explain delete from student where rownum < 3 and rownum < 5;
|
||||
explain delete from student where rownum > 3;
|
||||
|
||||
-- have not been optimized yet
|
||||
explain select * from student where rownum < 6.5;
|
||||
explain select * from student where rownum <= 6.5;
|
||||
explain select * from student where rownum = 6.5;
|
||||
explain select * from student where rownum != 6.5;
|
||||
explain select * from student where rownum > 6.5;
|
||||
explain select * from student where rownum >= 6.5;
|
||||
|
||||
explain delete from student where 3 > rownum;
|
||||
explain delete from student where 3 < rownum;
|
||||
|
||||
explain delete from student where rownum < 5 or rownum < 6;
|
||||
explain delete from student where rownum > 5 or rownum > 6;
|
||||
|
||||
drop table student;
|
||||
drop table test;
|
Reference in New Issue
Block a user