add common table expression in MySQL (#314)
This commit is contained in:
parent
5f209b30fe
commit
153f16ad8a
@ -12013,6 +12013,16 @@ static struct ObStrErrorInit
|
||||
ORACLE_ERRNO[-OB_ERR_ILL_NAME_STRING] = 21560;
|
||||
ORACLE_STR_ERROR[-OB_ERR_ILL_NAME_STRING] = "ORA-21560: unexpected name string '%.*s'";
|
||||
ORACLE_STR_USER_ERROR[-OB_ERR_ILL_NAME_STRING] = "ORA-21560: unexpected name string '%.*s'";
|
||||
ERROR_NAME[-OB_ERR_CTE_NEED_QUERY_BLOCKS] = "OB_ERR_CTE_NEED_QUERY_BLOCKS";
|
||||
ERROR_CAUSE[-OB_ERR_CTE_NEED_QUERY_BLOCKS] = "Internal Error";
|
||||
ERROR_SOLUTION[-OB_ERR_CTE_NEED_QUERY_BLOCKS] = "Contact OceanBase Support";
|
||||
MYSQL_ERRNO[-OB_ERR_CTE_NEED_QUERY_BLOCKS] = -1;
|
||||
SQLSTATE[-OB_ERR_CTE_NEED_QUERY_BLOCKS] = "HY000";
|
||||
STR_ERROR[-OB_ERR_CTE_NEED_QUERY_BLOCKS] = "Recursive Common Table Expression should have one or more non-recursive query blocks followed by one or more recursive ones";
|
||||
STR_USER_ERROR[-OB_ERR_CTE_NEED_QUERY_BLOCKS] = "Recursive Common Table Expression should have one or more non-recursive query blocks followed by one or more recursive ones: %s";
|
||||
ORACLE_ERRNO[-OB_ERR_CTE_NEED_QUERY_BLOCKS] = 600;
|
||||
ORACLE_STR_ERROR[-OB_ERR_CTE_NEED_QUERY_BLOCKS] = "ORA-00600: internal error code, arguments: -5933, Recursive Common Table Expression should have one or more non-recursive query blocks followed by one or more recursive ones";
|
||||
ORACLE_STR_USER_ERROR[-OB_ERR_CTE_NEED_QUERY_BLOCKS] = "ORA-00600: internal error code, arguments: -5933, Recursive Common Table Expression should have one or more non-recursive query blocks followed by one or more recursive ones: %s";
|
||||
ERROR_NAME[-OB_ERR_INCORRECT_VALUE_FOR_FUNCTION] = "OB_ERR_INCORRECT_VALUE_FOR_FUNCTION";
|
||||
ERROR_CAUSE[-OB_ERR_INCORRECT_VALUE_FOR_FUNCTION] = "Internal Error";
|
||||
ERROR_SOLUTION[-OB_ERR_INCORRECT_VALUE_FOR_FUNCTION] = "Contact OceanBase Support";
|
||||
|
@ -1320,6 +1320,7 @@ DEFINE_ERROR_EXT(OB_ERR_WINDOW_NAME_IS_NOT_DEFINE, -5929, -1, "HY000", "Window n
|
||||
DEFINE_ORACLE_ERROR(OB_ERR_OPEN_CURSORS_EXCEEDED, -5930, -1, "HY000", "maximum open cursors exceeded", 1000, "maximum open cursors exceeded");
|
||||
DEFINE_ORACLE_ERROR(OB_ERR_ARG_INVALID, -5931, -1, "HY000", "argument is null, invalid, or out of range", 21560, "argument %.*s is null, invalid, or out of range");
|
||||
DEFINE_ORACLE_ERROR(OB_ERR_ILL_NAME_STRING, -5932, -1, "HY000", "unexpected name string", 21560, "unexpected name string '%.*s'");
|
||||
DEFINE_ERROR_EXT(OB_ERR_CTE_NEED_QUERY_BLOCKS, -5933, -1, "HY000", "Recursive Common Table Expression should have one or more non-recursive query blocks followed by one or more recursive ones", "Recursive Common Table Expression should have one or more non-recursive query blocks followed by one or more recursive ones: %s");
|
||||
DEFINE_ERROR_EXT(OB_ERR_INCORRECT_VALUE_FOR_FUNCTION, -5936, ER_WRONG_VALUE_FOR_TYPE, "HY000", "Incorrect value for function", "Incorrect %.*s value: '%.*s' for function %.*s");
|
||||
DEFINE_ERROR_EXT(OB_ERR_USER_EXCEED_RESOURCE, -5967, 1226, "42000", "User has exceeded the resource", "User '%.*s' has exceeded the '%s' resource (current value: %lu)");
|
||||
|
||||
|
@ -1026,6 +1026,7 @@ constexpr int OB_ERR_WINDOW_NAME_IS_NOT_DEFINE = -5929;
|
||||
constexpr int OB_ERR_OPEN_CURSORS_EXCEEDED = -5930;
|
||||
constexpr int OB_ERR_ARG_INVALID = -5931;
|
||||
constexpr int OB_ERR_ILL_NAME_STRING = -5932;
|
||||
constexpr int OB_ERR_CTE_NEED_QUERY_BLOCKS = -5933;
|
||||
constexpr int OB_ERR_INCORRECT_VALUE_FOR_FUNCTION = -5936;
|
||||
constexpr int OB_ERR_USER_EXCEED_RESOURCE = -5967;
|
||||
constexpr int OB_TRANSACTION_SET_VIOLATION = -6001;
|
||||
@ -2428,6 +2429,7 @@ constexpr int OB_ERR_INVALID_DATE_MSG_FMT_V2 = -4219;
|
||||
#define OB_ERR_OPEN_CURSORS_EXCEEDED__USER_ERROR_MSG "maximum open cursors exceeded"
|
||||
#define OB_ERR_ARG_INVALID__USER_ERROR_MSG "argument is null, invalid, or out of range"
|
||||
#define OB_ERR_ILL_NAME_STRING__USER_ERROR_MSG "unexpected name string"
|
||||
#define OB_ERR_CTE_NEED_QUERY_BLOCKS__USER_ERROR_MSG "Recursive Common Table Expression should have one or more non-recursive query blocks followed by one or more recursive ones: %s"
|
||||
#define OB_ERR_INCORRECT_VALUE_FOR_FUNCTION__USER_ERROR_MSG "Incorrect %.*s value: '%.*s' for function %.*s"
|
||||
#define OB_ERR_USER_EXCEED_RESOURCE__USER_ERROR_MSG "User '%.*s' has exceeded the '%s' resource (current value: %lu)"
|
||||
#define OB_TRANSACTION_SET_VIOLATION__USER_ERROR_MSG "Transaction set changed during the execution"
|
||||
@ -3848,6 +3850,7 @@ constexpr int OB_ERR_INVALID_DATE_MSG_FMT_V2 = -4219;
|
||||
#define OB_ERR_OPEN_CURSORS_EXCEEDED__ORA_USER_ERROR_MSG "ORA-01000: maximum open cursors exceeded"
|
||||
#define OB_ERR_ARG_INVALID__ORA_USER_ERROR_MSG "ORA-21560: argument %.*s is null, invalid, or out of range"
|
||||
#define OB_ERR_ILL_NAME_STRING__ORA_USER_ERROR_MSG "ORA-21560: unexpected name string '%.*s'"
|
||||
#define OB_ERR_CTE_NEED_QUERY_BLOCKS__ORA_USER_ERROR_MSG "ORA-00600: internal error code, arguments: -5933, Recursive Common Table Expression should have one or more non-recursive query blocks followed by one or more recursive ones: %s"
|
||||
#define OB_ERR_INCORRECT_VALUE_FOR_FUNCTION__ORA_USER_ERROR_MSG "ORA-00600: internal error code, arguments: -5936, Incorrect %.*s value: '%.*s' for function %.*s"
|
||||
#define OB_ERR_USER_EXCEED_RESOURCE__ORA_USER_ERROR_MSG "ORA-00600: internal error code, arguments: -5967, User '%.*s' has exceeded the '%s' resource (current value: %lu)"
|
||||
#define OB_TRANSACTION_SET_VIOLATION__ORA_USER_ERROR_MSG "ORA-00600: internal error code, arguments: -6001, Transaction set changed during the execution"
|
||||
|
@ -272,6 +272,7 @@ READ { REPUT_TOKEN_NEG_SIGN(READ); }
|
||||
READ_WRITE { REPUT_TOKEN_NEG_SIGN(READ_WRITE); }
|
||||
READS { REPUT_TOKEN_NEG_SIGN(READS); }
|
||||
REAL { REPUT_TOKEN_NEG_SIGN(REAL); }
|
||||
RECURSIVE { REPUT_TOKEN_NEG_SIGN(RECURSIVE); }
|
||||
RELEASE { REPUT_TOKEN_NEG_SIGN(RELEASE); }
|
||||
REFERENCES { REPUT_TOKEN_NEG_SIGN(REFERENCES); }
|
||||
REGEXP { REPUT_TOKEN_NEG_SIGN(REGEXP); }
|
||||
|
@ -331,6 +331,7 @@ END_P SET_VAR DELIMITER
|
||||
%type <node> insert_vals_list insert_vals value_or_values
|
||||
%type <node> select_with_parens select_no_parens select_clause select_into no_table_select_with_order_and_limit simple_select_with_order_and_limit select_with_parens_with_order_and_limit select_clause_set select_clause_set_left select_clause_set_right select_clause_set_with_order_and_limit
|
||||
%type <node> simple_select no_table_select limit_clause select_expr_list
|
||||
%type <node> with_select with_clause with_list common_table_expr opt_column_alias_name_list alias_name_list column_alias_name
|
||||
%type <node> opt_where opt_hint_value opt_groupby opt_rollup opt_order_by order_by opt_having groupby_clause
|
||||
%type <node> opt_limit_clause limit_expr opt_for_update opt_for_update_wait
|
||||
%type <node> sort_list sort_key opt_asc_desc sort_list_for_group_by sort_key_for_group_by opt_asc_desc_for_group_by opt_column_id
|
||||
@ -6645,6 +6646,10 @@ select_no_parens opt_when
|
||||
{
|
||||
$$ = $1;
|
||||
}
|
||||
| with_select
|
||||
{
|
||||
$$ = $1;
|
||||
}
|
||||
;
|
||||
|
||||
// for select_into
|
||||
@ -6667,7 +6672,10 @@ select_no_parens into_clause
|
||||
select_with_parens:
|
||||
'(' select_no_parens ')' { $$ = $2; }
|
||||
| '(' select_with_parens ')' { $$ = $2; }
|
||||
;
|
||||
| '(' with_select ')'
|
||||
{
|
||||
$$ = $2;
|
||||
};
|
||||
|
||||
select_no_parens:
|
||||
select_clause opt_for_update
|
||||
@ -8880,6 +8888,135 @@ OUTER { $$ = NULL; }
|
||||
| /* EMPTY */ { $$ = NULL; }
|
||||
;
|
||||
|
||||
/*****************************************************************************
|
||||
*
|
||||
* with clause (common table expression) (Mysql CTE grammer implement)
|
||||
*
|
||||
*
|
||||
*****************************************************************************/
|
||||
|
||||
|
||||
with_select:
|
||||
with_clause select_no_parens opt_when
|
||||
{
|
||||
$$ = $2;
|
||||
$$->children_[PARSE_SELECT_WHEN] = $3;
|
||||
if (NULL == $$->children_[PARSE_SELECT_FOR_UPD] && NULL != $3)
|
||||
{
|
||||
malloc_terminal_node($$->children_[PARSE_SELECT_FOR_UPD], result->malloc_pool_, T_INT);
|
||||
$$->children_[PARSE_SELECT_FOR_UPD]->value_ = -1;
|
||||
}
|
||||
$$->children_[PARSE_SELECT_WITH] = $1;
|
||||
}
|
||||
| with_clause select_with_parens
|
||||
{
|
||||
$$ = $2;
|
||||
$$->children_[PARSE_SELECT_WITH] = $1;
|
||||
}
|
||||
;
|
||||
|
||||
with_clause:
|
||||
WITH with_list
|
||||
{
|
||||
ParseNode *with_list = NULL;
|
||||
merge_nodes(with_list, result, T_WITH_CLAUSE_LIST, $2);
|
||||
$$ = with_list;
|
||||
$$->value_ = 0;
|
||||
}
|
||||
|
|
||||
WITH RECURSIVE with_list
|
||||
{
|
||||
ParseNode *with_list = NULL;
|
||||
merge_nodes(with_list, result, T_WITH_CLAUSE_LIST, $3);
|
||||
$$ = with_list;
|
||||
$$->value_ = 1;
|
||||
}/*
|
||||
|
|
||||
WITH RECURSIVE common_table_expr
|
||||
{
|
||||
$$ = $3;
|
||||
$$->value_ = 0;
|
||||
}*/
|
||||
;
|
||||
|
||||
with_list:
|
||||
with_list ',' common_table_expr
|
||||
{
|
||||
malloc_non_terminal_node($$, result->malloc_pool_, T_LINK_NODE, 2, $1, $3);
|
||||
}
|
||||
|common_table_expr
|
||||
{
|
||||
$$ = $1;
|
||||
}
|
||||
;
|
||||
|
||||
|
||||
common_table_expr:
|
||||
relation_name opt_column_alias_name_list AS '(' select_no_parens ')'
|
||||
{
|
||||
malloc_non_terminal_node($$, result->malloc_pool_, T_WITH_CLAUSE_AS, 5, $1, $2, $5, NULL, NULL);
|
||||
}
|
||||
| relation_name opt_column_alias_name_list AS '(' with_select ')'
|
||||
{
|
||||
malloc_non_terminal_node($$, result->malloc_pool_, T_WITH_CLAUSE_AS, 5, $1, $2, $5, NULL, NULL);
|
||||
}
|
||||
| relation_name opt_column_alias_name_list AS '(' select_with_parens ')'
|
||||
{
|
||||
if ($5->children_[PARSE_SELECT_ORDER] != NULL && $5->children_[PARSE_SELECT_FETCH] == NULL) {
|
||||
yyerror(NULL, result, "only order by clause can't occur subquery\n");
|
||||
YYABORT_PARSE_SQL_ERROR;
|
||||
} else {
|
||||
malloc_non_terminal_node($$, result->malloc_pool_, T_WITH_CLAUSE_AS, 5, $1, $2, $5, NULL, NULL);
|
||||
}
|
||||
}
|
||||
;
|
||||
|
||||
opt_column_alias_name_list:
|
||||
'(' alias_name_list ')'
|
||||
{
|
||||
ParseNode *col_alias_list = NULL;
|
||||
merge_nodes(col_alias_list, result, T_COLUMN_LIST, $2);
|
||||
$$ = col_alias_list;
|
||||
}
|
||||
|/*EMPTY*/
|
||||
{ $$ = NULL; }
|
||||
;
|
||||
|
||||
alias_name_list:
|
||||
column_alias_name
|
||||
{
|
||||
$$ = $1;
|
||||
}
|
||||
|alias_name_list ',' column_alias_name
|
||||
{
|
||||
malloc_non_terminal_node($$, result->malloc_pool_, T_LINK_NODE, 2, $1, $3);
|
||||
}
|
||||
;
|
||||
|
||||
column_alias_name:
|
||||
column_name
|
||||
{
|
||||
$$ = $1;
|
||||
}
|
||||
;
|
||||
|
||||
|
||||
/*
|
||||
search_list:
|
||||
search_key
|
||||
{ $$ = $1; }
|
||||
| search_list ',' search_key
|
||||
{ malloc_non_terminal_node($$, result->malloc_pool_, T_LINK_NODE, 2, $1, $3); }
|
||||
;
|
||||
|
||||
search_key:
|
||||
column_name opt_asc_desc
|
||||
{
|
||||
malloc_non_terminal_node($$, result->malloc_pool_, T_SORT_KEY, 2, $1, $2);
|
||||
}
|
||||
;*/
|
||||
|
||||
|
||||
/*****************************************************************************
|
||||
*
|
||||
* CREATE OUTLINE grammar
|
||||
@ -13189,6 +13326,7 @@ ACCOUNT
|
||||
| REBUILD
|
||||
| RECOVER
|
||||
| RECOVERY
|
||||
| RECURSIVE
|
||||
| RECYCLE
|
||||
| RECYCLEBIN
|
||||
| ROTATE
|
||||
|
File diff suppressed because it is too large
Load Diff
File diff suppressed because it is too large
Load Diff
File diff suppressed because it is too large
Load Diff
@ -98,6 +98,7 @@ int ObSelectResolver::do_resolve_set_query_in_cte(const ParseNode& parse_tree)
|
||||
right_resolver.set_current_level(current_level_);
|
||||
right_resolver.set_in_set_query(true);
|
||||
right_resolver.set_parent_namespace_resolver(parent_namespace_resolver_);
|
||||
right_resolver.set_resolver(&left_resolver);
|
||||
|
||||
OC((left_resolver.set_cte_ctx)(cte_ctx_));
|
||||
OC((right_resolver.set_cte_ctx)(cte_ctx_));
|
||||
@ -124,6 +125,7 @@ int ObSelectResolver::do_resolve_set_query_in_cte(const ParseNode& parse_tree)
|
||||
LOG_WARN("failed to identify anchor member", K(ret));
|
||||
} else if (!need_swap_child) {
|
||||
left_select_stmt = identify_anchor_resolver.get_child_stmt();
|
||||
right_resolver.set_resolver(&identify_anchor_resolver);
|
||||
} else {
|
||||
left_member = PARSE_SELECT_LATER;
|
||||
right_member = PARSE_SELECT_FORMER;
|
||||
@ -136,6 +138,26 @@ int ObSelectResolver::do_resolve_set_query_in_cte(const ParseNode& parse_tree)
|
||||
}
|
||||
}
|
||||
|
||||
if (OB_SUCC(ret)) {
|
||||
if (!params_.has_cte_param_list_ && right_resolver.saved_left_resolver != NULL &&
|
||||
!right_resolver.saved_left_resolver->cte_ctx_.cte_col_names_.empty()) {
|
||||
right_resolver.cte_ctx_.cte_col_names_.reset();
|
||||
cte_ctx_.cte_col_names_.reset();
|
||||
for (int64_t i = 0; OB_SUCC(ret) && i < right_resolver.saved_left_resolver->cte_ctx_.cte_col_names_.count(); ++i) {
|
||||
if (OB_FAIL(right_resolver.cte_ctx_.cte_col_names_.push_back(
|
||||
right_resolver.saved_left_resolver->cte_ctx_.cte_col_names_.at(i)))) { // to right resolver
|
||||
ret = OB_ERR_UNEXPECTED;
|
||||
LOG_WARN("pass cte column name to child resolver failed");
|
||||
}
|
||||
if (OB_FAIL(cte_ctx_.cte_col_names_.push_back(
|
||||
right_resolver.saved_left_resolver->cte_ctx_.cte_col_names_.at(i)))) { // to parent resolver
|
||||
ret = OB_ERR_UNEXPECTED;
|
||||
LOG_WARN("pass cte column name to child resolver failed");
|
||||
}
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
if (OB_FAIL(ret)) {
|
||||
} else if (OB_FALSE_IT(right_resolver.cte_ctx_.set_recursive_right_branch(
|
||||
left_select_stmt, parse_tree.children_[left_member], !select_stmt->is_set_distinct()))) {
|
||||
@ -449,6 +471,7 @@ int ObSelectResolver::set_cte_ctx(ObCteResolverCtx& cte_ctx, bool copy_col_name
|
||||
{
|
||||
int ret = OB_SUCCESS;
|
||||
cte_ctx_ = cte_ctx;
|
||||
cte_ctx_.is_recursive_cte_ = false;
|
||||
cte_ctx_.cte_col_names_.reset();
|
||||
cte_ctx_.is_cte_subquery_ = in_subquery;
|
||||
if (cte_ctx_.is_with_resolver())
|
||||
@ -1517,6 +1540,13 @@ int ObSelectResolver::resolve_field_list(const ParseNode& node)
|
||||
} else { /*do nothing*/
|
||||
}
|
||||
|
||||
// add for cte:
|
||||
if (OB_SUCC(ret) && !params_.has_cte_param_list_) {
|
||||
if (OB_FAIL(cte_ctx_.cte_col_names_.push_back(select_item.alias_name_))) {
|
||||
LOG_WARN("push back column alia name failed", K(ret));
|
||||
}
|
||||
}
|
||||
|
||||
} // end for
|
||||
|
||||
// for aggr exprs in having clause to remove duplicate;
|
||||
@ -2130,12 +2160,12 @@ int ObSelectResolver::resolve_with_clause(const ParseNode* node, bool same_level
|
||||
ObSelectStmt* select_stmt = NULL;
|
||||
TableItem* table_item = NULL;
|
||||
bool duplicate_name = false;
|
||||
if (NULL != node && cte_ctx_.is_with_resolver() && same_level == false){
|
||||
LOG_DEBUG("same_level = false, oracle not supported, mysql feature");
|
||||
}
|
||||
if (OB_ISNULL(select_stmt = get_select_stmt())) {
|
||||
ret = OB_INVALID_ARGUMENT;
|
||||
LOG_WARN("invalid argument", K(ret), K(select_stmt), K_(node->type));
|
||||
} else if (NULL != node && cte_ctx_.is_with_resolver() && same_level == false) {
|
||||
ret = OB_ERR_UNSUPPORTED_USE_OF_CTE;
|
||||
LOG_WARN("invalid argument, oracle cte do not support a with clause nest", K(select_stmt), K_(node->type));
|
||||
} else if (OB_ISNULL(node)) {
|
||||
// do nothing
|
||||
} else if (OB_UNLIKELY(node->type_ != T_WITH_CLAUSE_LIST)) {
|
||||
@ -2144,6 +2174,10 @@ int ObSelectResolver::resolve_with_clause(const ParseNode* node, bool same_level
|
||||
LOG_WARN("resolver with_clause_as met unexpected node type", K_(node->type));
|
||||
} else {
|
||||
int num_child = node->num_child_;
|
||||
if (node->value_ == 0)
|
||||
params_.has_recursive_word = false;
|
||||
else
|
||||
params_.has_recursive_word = true;
|
||||
for (int64_t i = 0; OB_SUCC(ret) && i < num_child; ++i) {
|
||||
// alias tblname [(alia colname1, alia colname2)](subquery) [search clause][cycle clause]
|
||||
ParseNode* child_node = node->children_[i];
|
||||
@ -2981,7 +3015,7 @@ int ObSelectResolver::add_fake_schema(ObSelectStmt* left_stmt)
|
||||
ObColumnRefRawExpr* select_expr = static_cast<ObColumnRefRawExpr*>(expr);
|
||||
ObColumnSchemaV2* new_col = static_cast<ObColumnSchemaV2*>(allocator_->alloc(sizeof(ObColumnSchemaV2)));
|
||||
new_col = new (new_col) ObColumnSchemaV2(allocator_);
|
||||
new_col->set_column_name(cte_ctx_.cte_col_names_.at(i));
|
||||
new_col->set_column_name(saved_left_resolver->cte_ctx_.cte_col_names_.at(i));
|
||||
new_col->set_tenant_id(tbl_schema->get_tenant_id());
|
||||
new_col->set_table_id(magic_table_id);
|
||||
new_col->set_column_id(magic_col_id + i);
|
||||
@ -3010,7 +3044,9 @@ int ObSelectResolver::get_opt_alias_colnames_for_recursive_cte(ObIArray<ObString
|
||||
int ret = OB_SUCCESS;
|
||||
if (OB_ISNULL(parse_tree)) {
|
||||
LOG_DEBUG("the opt_alias_colnames parse tree is null");
|
||||
params_.has_cte_param_list_ = false;
|
||||
} else {
|
||||
params_.has_cte_param_list_ = true;
|
||||
int64_t alias_num = parse_tree->num_child_;
|
||||
for (int64_t i = 0; OB_SUCC(ret) && i < alias_num; ++i) {
|
||||
if (parse_tree->children_[i]->str_len_ <= 0) {
|
||||
@ -5456,7 +5492,12 @@ int ObSelectResolver::identify_anchor_member(
|
||||
if (OB_FAIL(identify_anchor_resolver.resolve_child_stmt(parse_tree))) {
|
||||
if (OB_ERR_NEED_INIT_BRANCH_IN_RECURSIVE_CTE == ret) {
|
||||
need_swap_childa = true;
|
||||
ret = OB_SUCCESS;
|
||||
if (is_oracle_mode()){
|
||||
ret = OB_SUCCESS;
|
||||
} else if (params_.has_recursive_word) {
|
||||
ret = OB_ERR_CTE_NEED_QUERY_BLOCKS; // mysql error: Recursive Common Table Expression 'cte' should have one or
|
||||
// more non-recursive query blocks followed by one or more recursive ones
|
||||
}
|
||||
} else {
|
||||
LOG_WARN("Failed to find anchor member", K(ret));
|
||||
}
|
||||
|
@ -229,6 +229,9 @@ public:
|
||||
}
|
||||
// function members
|
||||
TO_STRING_KV(K_(has_calc_found_rows), K_(has_top_limit), K_(in_set_query), K_(in_subquery));
|
||||
void set_resolver(ObSelectResolver* resolver){
|
||||
saved_left_resolver = resolver;
|
||||
}
|
||||
|
||||
protected:
|
||||
int resolve_set_query(const ParseNode& parse_node);
|
||||
@ -432,6 +435,8 @@ protected:
|
||||
bool in_subquery_;
|
||||
// query is subquery in exists
|
||||
bool in_exists_subquery_;
|
||||
ObSelectResolver* saved_left_resolver = NULL;
|
||||
// used to store left resolver and get alias name
|
||||
ObStandardGroupChecker standard_group_checker_;
|
||||
const TransposeItem* transpose_item_;
|
||||
|
||||
|
@ -287,6 +287,8 @@ struct ObResolverParams {
|
||||
new_gen_wid_(1),
|
||||
is_multi_table_insert_(false),
|
||||
is_resolve_table_function_expr_(false),
|
||||
has_cte_param_list_(false),
|
||||
has_recursive_word(false),
|
||||
is_column_ref_(true)
|
||||
{}
|
||||
bool is_force_trace_log()
|
||||
@ -340,6 +342,8 @@ private:
|
||||
public:
|
||||
bool is_multi_table_insert_; // used to mark is multi table insert
|
||||
bool is_resolve_table_function_expr_; // used to mark resolve table function expr.
|
||||
bool has_cte_param_list_;
|
||||
bool has_recursive_word;
|
||||
bool is_column_ref_; // used to mark normal column ref
|
||||
};
|
||||
} // end namespace sql
|
||||
|
2787
test/mysql_test/test_suite/with_clause/r/mysql/basic_mysql.result
Normal file
2787
test/mysql_test/test_suite/with_clause/r/mysql/basic_mysql.result
Normal file
File diff suppressed because it is too large
Load Diff
@ -0,0 +1,72 @@
|
||||
with cte(a,b) as (select 1 from dual) select * from cte;
|
||||
ERROR 5740 (HY000): number of WITH clause column names does not match number of elements in select list
|
||||
|
||||
with cte(a,b) as (with cte2(a,b) as (select 1,1 from dual) select a,b from cte) select * from cte;
|
||||
ERROR 5742 (HY000): recursive WITH clause must use a UNION ALL operation
|
||||
|
||||
with cte(a,a) as (select 1 from dual) select * from cte;
|
||||
ERROR 5751 (HY000): duplicate name found in column alias list for WITH clause
|
||||
|
||||
with cte as (select 1,1 from dual union all select a+1,b+1 from cte where cte.a < 10) select * from cte;
|
||||
ERROR 1054 (42S22): Unknown column 'cte.a' in 'where clause'
|
||||
|
||||
# MySQL不支持search depth关键字
|
||||
with cte(a,b,c) as
|
||||
(
|
||||
select 1,2,3 from dual
|
||||
union all
|
||||
select a+1,b+1,c+1 from cte where cte.c < 10
|
||||
) search depth first by d set pcol select * from cte;
|
||||
ERROR 1064 (42000): You have an error in your SQL syntax; check the manual that corresponds to your OceanBase version for the right syntax to use near 'search depth first by d set pcol select * from cte' at line 6
|
||||
|
||||
# MySQL不支持cycle关键字
|
||||
with cte(n, x) as (select /*+ materialize */ 1,2 from dual) cycle n,n set iscyc to 'aaaaay' default 'n' select * from cte;
|
||||
ERROR 1064 (42000): You have an error in your SQL syntax; check the manual that corresponds to your OceanBase version for the right syntax to use near 'cycle n,n set iscyc to 'aaaaay' default 'n' select * from cte' at line 1
|
||||
|
||||
with cte(a,b,c) as
|
||||
(
|
||||
select 1,2,3 from dual
|
||||
union
|
||||
select a+1,b+1,c+1 from cte, cte b where cte.c < 10 and b.c = cte.c
|
||||
) select * from cte;
|
||||
ERROR 5742 (HY000): recursive WITH clause must use a UNION ALL operation
|
||||
|
||||
with cte(a,b,c) as
|
||||
(
|
||||
select 1,2,3 from dual
|
||||
union all
|
||||
select 1,2,3 from dual
|
||||
union all
|
||||
select a+1,b+1,c+1 from cte, cte b where cte.c < 10 and b.c = cte.c
|
||||
) select * from cte;
|
||||
ERROR 5762 (HY000): recursive query name referenced more than once in recursive branch of recursive WITH clause element
|
||||
|
||||
with t1 as (select c1 from t1) select * from t1;
|
||||
ERROR 5741 (HY000): recursive WITH clause must have column alias list
|
||||
|
||||
## success
|
||||
with cte1(a,b) as (select 'a','b' from dual), cte2 as (select * from cte1 where b > 'c'), cte3 as (select * from cte2 where a > 1 union select * from cte2 where a > 1) select * from cte3;
|
||||
Empty set
|
||||
|
||||
with cte(a) as (select 1,1 from dual union all select a+1, a+1 from cte where a+1 < 10) select * from cte;
|
||||
ERROR 5740 (HY000): number of WITH clause column names does not match number of elements in select list
|
||||
|
||||
with cte(n) AS (select 1 from dual UNION ALL select n+1 from cte where n < 3 UNION ALL select 2 from dual) select * from cte;
|
||||
ERROR 5743 (HY000): UNION ALL operation in recursive WITH clause must have only two branches
|
||||
|
||||
with cte(n) AS ( select 1 from dual UNION ALL select sum(n+1) from cte) select * from cte;
|
||||
ERROR 5758 (HY000): unsupported operation in recursive branch of recursive WITH clause
|
||||
|
||||
with cte(n) AS ( select 1 from dual UNION ALL select (select 1 from dual) from cte where cte.n < 2) select * from cte;
|
||||
ERROR 5746 (HY000): cycle detected while executing recursive WITH query
|
||||
|
||||
with cte (c1, c2, c3) as ( select * from ( select c1, c2, c3 from t1 union select c1, c2, c3 from t1) where c1 = 1 union all select * from t1 join cte c on t1.c1 = c.c1 where c.c1 < 10 ) select * from cte;
|
||||
ERROR 1222 (21000): The used SELECT statements have a different number of columns
|
||||
|
||||
with cte(n) AS ( select 1 from cte) select * from cte;
|
||||
ERROR 5742 (HY000): recursive WITH clause must use a UNION ALL operation
|
||||
|
||||
with cte(n) AS (select 1 from dual UNION ALL select n+1 from cte where n < 3 order by n ) select * from cte;
|
||||
ERROR 1054 (42S22): Unknown column 'n' in 'order clause'
|
||||
|
||||
|
@ -0,0 +1,796 @@
|
||||
WITH RECURSIVE cte (n) AS
|
||||
(
|
||||
SELECT 1
|
||||
UNION ALL
|
||||
SELECT n + 1 FROM cte WHERE n < 5
|
||||
)
|
||||
SELECT * FROM cte;
|
||||
+------+
|
||||
| n |
|
||||
+------+
|
||||
| 1 |
|
||||
| 2 |
|
||||
| 3 |
|
||||
| 4 |
|
||||
| 5 |
|
||||
+------+
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT 1 AS n, CAST('abc' AS CHAR(20)) AS str
|
||||
UNION ALL
|
||||
SELECT n + 1, CONCAT(str, str) FROM cte WHERE n < 3
|
||||
)
|
||||
SELECT * FROM cte;
|
||||
+------+--------------+
|
||||
| n | str |
|
||||
+------+--------------+
|
||||
| 1 | abc |
|
||||
| 2 | abcabc |
|
||||
| 3 | abcabcabcabc |
|
||||
+------+--------------+
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT 1 AS n, 1 AS p, -1 AS q
|
||||
UNION ALL
|
||||
SELECT n + 1, q * 2, p * 2 FROM cte WHERE n < 5
|
||||
)
|
||||
SELECT * FROM cte;
|
||||
+------+------+------+
|
||||
| n | p | q |
|
||||
+------+------+------+
|
||||
| 1 | 1 | -1 |
|
||||
| 2 | -2 | 2 |
|
||||
| 3 | 4 | -4 |
|
||||
| 4 | -8 | 8 |
|
||||
| 5 | 16 | -16 |
|
||||
+------+------+------+
|
||||
|
||||
WITH RECURSIVE fibonacci (n, fib_n, next_fib_n) AS
|
||||
(
|
||||
SELECT 1, 0, 1
|
||||
UNION ALL
|
||||
SELECT n + 1, next_fib_n, fib_n + next_fib_n
|
||||
FROM fibonacci WHERE n < 10
|
||||
)
|
||||
SELECT * FROM fibonacci;
|
||||
+------+-------+------------+
|
||||
| n | fib_n | next_fib_n |
|
||||
+------+-------+------------+
|
||||
| 1 | 0 | 1 |
|
||||
| 2 | 1 | 1 |
|
||||
| 3 | 1 | 2 |
|
||||
| 4 | 2 | 3 |
|
||||
| 5 | 3 | 5 |
|
||||
| 6 | 5 | 8 |
|
||||
| 7 | 8 | 13 |
|
||||
| 8 | 13 | 21 |
|
||||
| 9 | 21 | 34 |
|
||||
| 10 | 34 | 55 |
|
||||
+------+-------+------------+
|
||||
|
||||
WITH RECURSIVE fibonacci (n, fib_n, next_fib_n) AS
|
||||
(
|
||||
SELECT 1, 0, 1
|
||||
UNION ALL
|
||||
SELECT n + 1, next_fib_n, fib_n + next_fib_n
|
||||
FROM fibonacci WHERE n < 10
|
||||
)
|
||||
SELECT fib_n FROM fibonacci WHERE n = 8;
|
||||
+-------+
|
||||
| fib_n |
|
||||
+-------+
|
||||
| 13 |
|
||||
+-------+
|
||||
|
||||
create table sales(date DATE,price NUMBER(7,2));
|
||||
insert into sales values(str_to_date('2017-01-03', '%Y-%m-%d'),100);
|
||||
insert into sales values(str_to_date('2017-01-03', '%Y-%m-%d'),200);
|
||||
insert into sales values(str_to_date('2017-01-06', '%Y-%m-%d'),50);
|
||||
insert into sales values(str_to_date('2017-01-08', '%Y-%m-%d'),10);
|
||||
insert into sales values(str_to_date('2017-01-08', '%Y-%m-%d'),20);
|
||||
insert into sales values(str_to_date('2017-01-08', '%Y-%m-%d'),150);
|
||||
insert into sales values(str_to_date('2017-01-10', '%Y-%m-%d'),5);
|
||||
|
||||
SELECT * FROM sales ORDER BY date, price;
|
||||
+------------+--------+
|
||||
| date | price |
|
||||
+------------+--------+
|
||||
| 2017-01-03 | 100.00 |
|
||||
| 2017-01-03 | 200.00 |
|
||||
| 2017-01-06 | 50.00 |
|
||||
| 2017-01-08 | 10.00 |
|
||||
| 2017-01-08 | 20.00 |
|
||||
| 2017-01-08 | 150.00 |
|
||||
| 2017-01-10 | 5.00 |
|
||||
+------------+--------+
|
||||
|
||||
SELECT date, SUM(price) AS sum_price
|
||||
FROM sales
|
||||
GROUP BY date
|
||||
ORDER BY date;
|
||||
+------------+-----------+
|
||||
| date | sum_price |
|
||||
+------------+-----------+
|
||||
| 2017-01-03 | 300.00 |
|
||||
| 2017-01-06 | 50.00 |
|
||||
| 2017-01-08 | 180.00 |
|
||||
| 2017-01-10 | 5.00 |
|
||||
+------------+-----------+
|
||||
|
||||
WITH RECURSIVE dates (date) AS
|
||||
(
|
||||
SELECT MIN(date) FROM sales
|
||||
UNION ALL
|
||||
SELECT date + INTERVAL 1 DAY FROM dates
|
||||
WHERE date + INTERVAL 1 DAY <= (SELECT MAX(date) FROM sales)
|
||||
)
|
||||
SELECT * FROM dates;
|
||||
+------------+
|
||||
| date |
|
||||
+------------+
|
||||
| 2017-01-03 |
|
||||
| 2017-01-04 |
|
||||
| 2017-01-05 |
|
||||
| 2017-01-06 |
|
||||
| 2017-01-07 |
|
||||
| 2017-01-08 |
|
||||
| 2017-01-09 |
|
||||
| 2017-01-10 |
|
||||
+------------+
|
||||
|
||||
WITH RECURSIVE dates (date) AS
|
||||
(
|
||||
SELECT MIN(date) FROM sales
|
||||
UNION ALL
|
||||
SELECT date + INTERVAL 1 DAY FROM dates
|
||||
WHERE date + INTERVAL 1 DAY <= (SELECT MAX(date) FROM sales)
|
||||
)
|
||||
SELECT dates.date, COALESCE(SUM(price), 0) AS sum_price
|
||||
FROM dates LEFT JOIN sales ON dates.date = sales.date
|
||||
GROUP BY dates.date
|
||||
ORDER BY dates.date;
|
||||
+------------+-----------+
|
||||
| date | sum_price |
|
||||
+------------+-----------+
|
||||
| 2017-01-03 | 300.00 |
|
||||
| 2017-01-04 | 0.00 |
|
||||
| 2017-01-05 | 0.00 |
|
||||
| 2017-01-06 | 50.00 |
|
||||
| 2017-01-07 | 0.00 |
|
||||
| 2017-01-08 | 180.00 |
|
||||
| 2017-01-09 | 0.00 |
|
||||
| 2017-01-10 | 5.00 |
|
||||
+------------+-----------+
|
||||
|
||||
################################################################################################
|
||||
### PART 1 SQL syntax
|
||||
################################################################################################
|
||||
|
||||
WITH cte1(txt) AS (SELECT "This "),
|
||||
cte2(txt) AS (SELECT CONCAT(cte1.txt,"is a ") FROM cte1),
|
||||
cte3(txt) AS (SELECT "nice query" UNION
|
||||
SELECT "query that rocks" UNION
|
||||
SELECT "query"),
|
||||
cte4(txt) AS (SELECT concat(cte2.txt, cte3.txt) FROM cte2, cte3)
|
||||
SELECT MAX(txt), MIN(txt) FROM cte4;
|
||||
+----------------------------+----------------------+
|
||||
| MAX(txt) | MIN(txt) |
|
||||
+----------------------------+----------------------+
|
||||
| This is a query that rocks | This is a nice query |
|
||||
+----------------------------+----------------------+
|
||||
|
||||
WITH RECURSIVE my_cte AS
|
||||
(
|
||||
SELECT 1 AS n
|
||||
UNION ALL
|
||||
SELECT 1+n FROM my_cte WHERE n<10
|
||||
)
|
||||
SELECT * FROM my_cte;
|
||||
+------+
|
||||
| n |
|
||||
+------+
|
||||
| 1 |
|
||||
| 2 |
|
||||
| 3 |
|
||||
| 4 |
|
||||
| 5 |
|
||||
| 6 |
|
||||
| 7 |
|
||||
| 8 |
|
||||
| 9 |
|
||||
| 10 |
|
||||
+------+
|
||||
|
||||
CREATE TABLE numbers
|
||||
WITH RECURSIVE my_cte(n) AS
|
||||
(
|
||||
SELECT 1
|
||||
UNION ALL
|
||||
SELECT 1+n FROM my_cte WHERE n<6
|
||||
)
|
||||
SELECT * FROM my_cte;
|
||||
SELECT * FROM numbers;
|
||||
+------+
|
||||
| n |
|
||||
+------+
|
||||
| 1 |
|
||||
| 2 |
|
||||
| 3 |
|
||||
| 4 |
|
||||
| 5 |
|
||||
| 6 |
|
||||
+------+
|
||||
|
||||
INSERT INTO numbers
|
||||
WITH RECURSIVE my_cte(n) AS
|
||||
(
|
||||
SELECT 1
|
||||
UNION ALL
|
||||
SELECT 1+n FROM my_cte WHERE n<6
|
||||
)
|
||||
SELECT * FROM my_cte;
|
||||
|
||||
SELECT * FROM numbers;
|
||||
+------+
|
||||
| n |
|
||||
+------+
|
||||
| 1 |
|
||||
| 2 |
|
||||
| 3 |
|
||||
| 4 |
|
||||
| 5 |
|
||||
| 6 |
|
||||
| 1 |
|
||||
| 2 |
|
||||
| 3 |
|
||||
| 4 |
|
||||
| 5 |
|
||||
| 6 |
|
||||
+------+
|
||||
|
||||
DELETE FROM numbers
|
||||
WHERE numbers.n >
|
||||
(
|
||||
WITH RECURSIVE my_cte(n) AS
|
||||
(
|
||||
SELECT 1
|
||||
UNION ALL
|
||||
SELECT 1+n FROM my_cte WHERE n<6
|
||||
)
|
||||
SELECT AVG(n)/2 FROM my_cte
|
||||
);
|
||||
SELECT * FROM numbers;
|
||||
+------+
|
||||
| n |
|
||||
+------+
|
||||
| 1 |
|
||||
| 1 |
|
||||
+------+
|
||||
|
||||
################################################################################################
|
||||
### PART 2 generating series
|
||||
################################################################################################
|
||||
WITH RECURSIVE my_cte AS
|
||||
(
|
||||
SELECT 1 as f, 1 as next_f
|
||||
UNION ALL
|
||||
SELECT next_f, f+next_f FROM my_cte WHERE f < 500
|
||||
)
|
||||
SELECT * FROM my_cte;
|
||||
+------+--------+
|
||||
| f | next_f |
|
||||
+------+--------+
|
||||
| 1 | 1 |
|
||||
| 1 | 2 |
|
||||
| 2 | 3 |
|
||||
| 3 | 5 |
|
||||
| 5 | 8 |
|
||||
| 8 | 13 |
|
||||
| 13 | 21 |
|
||||
| 21 | 34 |
|
||||
| 34 | 55 |
|
||||
| 55 | 89 |
|
||||
| 89 | 144 |
|
||||
| 144 | 233 |
|
||||
| 233 | 377 |
|
||||
| 377 | 610 |
|
||||
| 610 | 987 |
|
||||
+------+--------+
|
||||
|
||||
WITH RECURSIVE
|
||||
digits AS
|
||||
(
|
||||
SELECT '0' AS d UNION ALL SELECT '1'
|
||||
),
|
||||
strings AS
|
||||
(
|
||||
SELECT CAST('' AS CHAR(4)) AS s
|
||||
UNION ALL
|
||||
SELECT CONCAT(strings.s, digits.d)
|
||||
FROM strings, digits
|
||||
WHERE LENGTH(strings.s) < 4
|
||||
)
|
||||
SELECT * FROM strings WHERE LENGTH(s)=4;
|
||||
+------+
|
||||
| s |
|
||||
+------+
|
||||
| 0000 |
|
||||
| 0001 |
|
||||
| 0010 |
|
||||
| 0011 |
|
||||
| 0100 |
|
||||
| 0101 |
|
||||
| 0110 |
|
||||
| 0111 |
|
||||
| 1000 |
|
||||
| 1001 |
|
||||
| 1010 |
|
||||
| 1011 |
|
||||
| 1100 |
|
||||
| 1101 |
|
||||
| 1110 |
|
||||
| 1111 |
|
||||
+------+
|
||||
|
||||
################################################################################################
|
||||
### PART 3 hierarchies
|
||||
################################################################################################
|
||||
CREATE TABLE category(
|
||||
category_id INT AUTO_INCREMENT PRIMARY KEY,
|
||||
name VARCHAR(20) NOT NULL,
|
||||
parent INT DEFAULT NULL
|
||||
);
|
||||
|
||||
INSERT INTO category VALUES(1,'ELECTRONICS',NULL),(2,'TELEVISIONS',1),(3,'TUBE',2),
|
||||
(4,'LCD',2),(5,'PLASMA',2),(6,'PORTABLE ELECTRONICS',1),(7,'MP3 PLAYERS',6),(8,'FLASH',7),
|
||||
(9,'CD PLAYERS',6),(10,'2 WAY RADIOS',6);
|
||||
|
||||
SELECT * FROM category ORDER BY category_id;
|
||||
+-------------+----------------------+--------+
|
||||
| category_id | name | parent |
|
||||
+-------------+----------------------+--------+
|
||||
| 1 | ELECTRONICS | NULL |
|
||||
| 2 | TELEVISIONS | 1 |
|
||||
| 3 | TUBE | 2 |
|
||||
| 4 | LCD | 2 |
|
||||
| 5 | PLASMA | 2 |
|
||||
| 6 | PORTABLE ELECTRONICS | 1 |
|
||||
| 7 | MP3 PLAYERS | 6 |
|
||||
| 8 | FLASH | 7 |
|
||||
| 9 | CD PLAYERS | 6 |
|
||||
| 10 | 2 WAY RADIOS | 6 |
|
||||
+-------------+----------------------+--------+
|
||||
|
||||
#Retrieving a Full Tree
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
# seed SELECT
|
||||
SELECT category_id, name FROM category WHERE parent IS NULL
|
||||
UNION ALL
|
||||
# recursive SELECT
|
||||
SELECT c.category_id, c.name FROM category c JOIN cte
|
||||
ON cte.category_id=c.parent # find children
|
||||
)
|
||||
SELECT category_id, name FROM cte;
|
||||
+-------------+----------------------+
|
||||
| category_id | name |
|
||||
+-------------+----------------------+
|
||||
| 1 | ELECTRONICS |
|
||||
| 6 | PORTABLE ELECTRONICS |
|
||||
| 2 | TELEVISIONS |
|
||||
| 10 | 2 WAY RADIOS |
|
||||
| 9 | CD PLAYERS |
|
||||
| 7 | MP3 PLAYERS |
|
||||
| 5 | PLASMA |
|
||||
| 4 | LCD |
|
||||
| 3 | TUBE |
|
||||
| 8 | FLASH |
|
||||
+-------------+----------------------+
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT category_id, name, 0 AS depth FROM category WHERE parent IS NULL
|
||||
UNION ALL
|
||||
SELECT c.category_id, c.name, cte.depth+1 FROM category c JOIN cte ON
|
||||
cte.category_id=c.parent
|
||||
)
|
||||
SELECT * FROM cte ORDER BY depth;
|
||||
+-------------+----------------------+-------+
|
||||
| category_id | name | depth |
|
||||
+-------------+----------------------+-------+
|
||||
| 1 | ELECTRONICS | 0 |
|
||||
| 6 | PORTABLE ELECTRONICS | 1 |
|
||||
| 2 | TELEVISIONS | 1 |
|
||||
| 10 | 2 WAY RADIOS | 2 |
|
||||
| 9 | CD PLAYERS | 2 |
|
||||
| 7 | MP3 PLAYERS | 2 |
|
||||
| 5 | PLASMA | 2 |
|
||||
| 4 | LCD | 2 |
|
||||
| 3 | TUBE | 2 |
|
||||
| 8 | FLASH | 3 |
|
||||
+-------------+----------------------+-------+
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT category_id, name, CAST(category_id AS CHAR(200)) AS path
|
||||
FROM category WHERE parent IS NULL
|
||||
UNION ALL
|
||||
SELECT c.category_id, c.name, CONCAT(cte.path, ",", c.category_id)
|
||||
FROM category c JOIN cte ON cte.category_id=c.parent
|
||||
)
|
||||
SELECT * FROM cte ORDER BY path;
|
||||
+-------------+----------------------+---------+
|
||||
| category_id | name | path |
|
||||
+-------------+----------------------+---------+
|
||||
| 1 | ELECTRONICS | 1 |
|
||||
| 2 | TELEVISIONS | 1,2 |
|
||||
| 3 | TUBE | 1,2,3 |
|
||||
| 4 | LCD | 1,2,4 |
|
||||
| 5 | PLASMA | 1,2,5 |
|
||||
| 6 | PORTABLE ELECTRONICS | 1,6 |
|
||||
| 10 | 2 WAY RADIOS | 1,6,10 |
|
||||
| 7 | MP3 PLAYERS | 1,6,7 |
|
||||
| 8 | FLASH | 1,6,7,8 |
|
||||
| 9 | CD PLAYERS | 1,6,9 |
|
||||
+-------------+----------------------+---------+
|
||||
|
||||
#Finding all the leaf nodes
|
||||
|
||||
SELECT category_id, name FROM category
|
||||
WHERE category_id NOT IN
|
||||
# IDs of all parents:
|
||||
(SELECT parent FROM category WHERE parent IS NOT NULL);
|
||||
+-------------+--------------+
|
||||
| category_id | name |
|
||||
+-------------+--------------+
|
||||
| 3 | TUBE |
|
||||
| 4 | LCD |
|
||||
| 5 | PLASMA |
|
||||
| 8 | FLASH |
|
||||
| 9 | CD PLAYERS |
|
||||
| 10 | 2 WAY RADIOS |
|
||||
+-------------+--------------+
|
||||
|
||||
#Retrieving a Single Path
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT name, parent FROM category WHERE name='FLASH'
|
||||
UNION ALL
|
||||
SELECT c.name, c.parent FROM category c JOIN cte
|
||||
ON c.category_id=cte.parent # find parent
|
||||
)
|
||||
SELECT * FROM cte;
|
||||
+----------------------+--------+
|
||||
| name | parent |
|
||||
+----------------------+--------+
|
||||
| FLASH | 7 |
|
||||
| MP3 PLAYERS | 6 |
|
||||
| PORTABLE ELECTRONICS | 1 |
|
||||
| ELECTRONICS | NULL |
|
||||
+----------------------+--------+
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT name, parent, 0 as depth FROM category WHERE name='FLASH'
|
||||
UNION ALL
|
||||
SELECT c.name, c.parent, cte.depth-1 FROM category c JOIN cte
|
||||
ON c.category_id=cte.parent
|
||||
)
|
||||
SELECT * FROM cte ORDER BY depth;
|
||||
+----------------------+--------+-------+
|
||||
| name | parent | depth |
|
||||
+----------------------+--------+-------+
|
||||
| ELECTRONICS | NULL | -3 |
|
||||
| PORTABLE ELECTRONICS | 1 | -2 |
|
||||
| MP3 PLAYERS | 6 | -1 |
|
||||
| FLASH | 7 | 0 |
|
||||
+----------------------+--------+-------+
|
||||
|
||||
#Finding the Depth of the Nodes
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT category_id, CAST(name AS CHAR(200)) AS name,
|
||||
CAST(category_id AS CHAR(200)) AS path,
|
||||
0 as depth
|
||||
FROM category WHERE parent IS NULL
|
||||
UNION ALL
|
||||
SELECT c.category_id,
|
||||
CONCAT(REPEAT(' ', cte.depth+1), c.name), # indentation
|
||||
CONCAT(cte.path, ",", c.category_id),
|
||||
cte.depth+1
|
||||
FROM category c JOIN cte ON
|
||||
cte.category_id=c.parent
|
||||
)
|
||||
SELECT * FROM cte ORDER BY path;
|
||||
+-------------+-----------------------+---------+-------+
|
||||
| category_id | name | path | depth |
|
||||
+-------------+-----------------------+---------+-------+
|
||||
| 1 | ELECTRONICS | 1 | 0 |
|
||||
| 2 | TELEVISIONS | 1,2 | 1 |
|
||||
| 3 | TUBE | 1,2,3 | 2 |
|
||||
| 4 | LCD | 1,2,4 | 2 |
|
||||
| 5 | PLASMA | 1,2,5 | 2 |
|
||||
| 6 | PORTABLE ELECTRONICS | 1,6 | 1 |
|
||||
| 10 | 2 WAY RADIOS | 1,6,10 | 2 |
|
||||
| 7 | MP3 PLAYERS | 1,6,7 | 2 |
|
||||
| 8 | FLASH | 1,6,7,8 | 3 |
|
||||
| 9 | CD PLAYERS | 1,6,9 | 2 |
|
||||
+-------------+-----------------------+---------+-------+
|
||||
|
||||
#Depth of a sub-tree
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT category_id, name,
|
||||
CAST(category_id AS CHAR(200)) AS path,
|
||||
0 as depth
|
||||
FROM category WHERE name='PORTABLE ELECTRONICS' # sub-tree root
|
||||
UNION ALL
|
||||
SELECT c.category_id,
|
||||
c.name,
|
||||
CONCAT(cte.path, ",", c.category_id),
|
||||
cte.depth+1
|
||||
FROM category c JOIN cte
|
||||
ON cte.category_id=c.parent
|
||||
)
|
||||
SELECT * FROM cte ORDER BY path;
|
||||
+-------------+----------------------+-------+-------+
|
||||
| category_id | name | path | depth |
|
||||
+-------------+----------------------+-------+-------+
|
||||
| 6 | PORTABLE ELECTRONICS | 6 | 0 |
|
||||
| 10 | 2 WAY RADIOS | 6,10 | 1 |
|
||||
| 7 | MP3 PLAYERS | 6,7 | 1 |
|
||||
| 8 | FLASH | 6,7,8 | 2 |
|
||||
| 9 | CD PLAYERS | 6,9 | 1 |
|
||||
+-------------+----------------------+-------+-------+
|
||||
|
||||
#Find the immediate subordinates of a node
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT category_id, name, 0 as depth
|
||||
FROM category WHERE name='PORTABLE ELECTRONICS'
|
||||
UNION ALL
|
||||
SELECT c.category_id, c.name, cte.depth+1
|
||||
FROM category c JOIN cte
|
||||
ON cte.category_id=c.parent
|
||||
WHERE cte.depth=0
|
||||
)
|
||||
SELECT * FROM cte;
|
||||
+-------------+----------------------+-------+
|
||||
| category_id | name | depth |
|
||||
+-------------+----------------------+-------+
|
||||
| 6 | PORTABLE ELECTRONICS | 0 |
|
||||
| 10 | 2 WAY RADIOS | 1 |
|
||||
| 9 | CD PLAYERS | 1 |
|
||||
| 7 | MP3 PLAYERS | 1 |
|
||||
+-------------+----------------------+-------+
|
||||
|
||||
#Aggregate functions in a nested set
|
||||
|
||||
CREATE TABLE product(
|
||||
category_id INT AUTO_INCREMENT PRIMARY KEY,
|
||||
name VARCHAR(20) NOT NULL,
|
||||
parent INT DEFAULT NULL
|
||||
);
|
||||
|
||||
INSERT INTO product VALUES(1,'ELECTRONICS',NULL),(2,'TELEVISIONS',1),(3,'TUBE',2),
|
||||
(4,'LCD',2),(5,'PLASMA',2),(6,'PORTABLE ELECTRONICS',1),(7,'MP3 PLAYERS',6),(8,'FLASH',7),
|
||||
(9,'CD PLAYERS',6),(10,'2 WAY RADIOS',6);
|
||||
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT c.category_id, c.name AS cat_name, c.parent, p.name AS prod_name
|
||||
FROM category c JOIN product p ON c.category_id=p.category_id
|
||||
UNION ALL
|
||||
SELECT c.category_id, c.name, c.parent, cte.prod_name
|
||||
FROM cte JOIN category c ON c.category_id=cte.parent
|
||||
)
|
||||
SELECT cat_name, COUNT(*) AS prod_in_cat FROM cte
|
||||
GROUP BY cat_name;
|
||||
+----------------------+-------------+
|
||||
| cat_name | prod_in_cat |
|
||||
+----------------------+-------------+
|
||||
| ELECTRONICS | 10 |
|
||||
| TELEVISIONS | 4 |
|
||||
| TUBE | 1 |
|
||||
| LCD | 1 |
|
||||
| PLASMA | 1 |
|
||||
| PORTABLE ELECTRONICS | 5 |
|
||||
| MP3 PLAYERS | 2 |
|
||||
| FLASH | 1 |
|
||||
| CD PLAYERS | 1 |
|
||||
| 2 WAY RADIOS | 1 |
|
||||
+----------------------+-------------+
|
||||
|
||||
|
||||
################################################################################################
|
||||
### PART 4 depth-first or breadth-first traversal, transitive closure, cycle avoidance
|
||||
################################################################################################
|
||||
|
||||
#Depth-first or breadth-first
|
||||
|
||||
CREATE TABLE tree (person CHAR(20), parent CHAR(20));
|
||||
INSERT INTO tree VALUES
|
||||
('Robert I', NULL),
|
||||
('Thurimbert', 'Robert I'),
|
||||
('Robert II', 'Thurimbert'),
|
||||
('Cancor', 'Thurimbert'),
|
||||
('Landrade', 'Thurimbert'),
|
||||
('Ingramm', 'Thurimbert'),
|
||||
('Robert III', 'Robert II'),
|
||||
('Chaudegrand', 'Landrade'),
|
||||
('Ermengarde', 'Ingramm');
|
||||
|
||||
WITH RECURSIVE descendants AS
|
||||
(
|
||||
SELECT person
|
||||
FROM tree
|
||||
WHERE person='Thurimbert'
|
||||
UNION ALL
|
||||
SELECT t.person
|
||||
FROM descendants d, tree t
|
||||
WHERE t.parent=d.person
|
||||
)
|
||||
SELECT * FROM descendants;
|
||||
+-------------+
|
||||
| person |
|
||||
+-------------+
|
||||
| Thurimbert |
|
||||
| Ingramm |
|
||||
| Landrade |
|
||||
| Cancor |
|
||||
| Robert II |
|
||||
| Ermengarde |
|
||||
| Chaudegrand |
|
||||
| Robert III |
|
||||
+-------------+
|
||||
|
||||
WITH RECURSIVE descendants AS
|
||||
(
|
||||
SELECT person, 1 as level
|
||||
FROM tree
|
||||
WHERE person='Thurimbert'
|
||||
UNION ALL
|
||||
SELECT t.person, d.level+1
|
||||
FROM descendants d, tree t
|
||||
WHERE t.parent=d.person
|
||||
)
|
||||
SELECT * FROM descendants ORDER BY level;
|
||||
+-------------+-------+
|
||||
| person | level |
|
||||
+-------------+-------+
|
||||
| Thurimbert | 1 |
|
||||
| Ingramm | 2 |
|
||||
| Landrade | 2 |
|
||||
| Cancor | 2 |
|
||||
| Robert II | 2 |
|
||||
| Ermengarde | 3 |
|
||||
| Chaudegrand | 3 |
|
||||
| Robert III | 3 |
|
||||
+-------------+-------+
|
||||
|
||||
WITH RECURSIVE descendants AS
|
||||
(
|
||||
SELECT person, CAST(person AS CHAR(500)) AS path
|
||||
FROM tree
|
||||
WHERE person='Thurimbert'
|
||||
UNION ALL
|
||||
SELECT t.person, CONCAT(d.path, ',', t.person)
|
||||
FROM descendants d, tree t
|
||||
WHERE t.parent=d.person
|
||||
)
|
||||
SELECT * FROM descendants ORDER BY path;
|
||||
+-------------+---------------------------------+
|
||||
| person | path |
|
||||
+-------------+---------------------------------+
|
||||
| Thurimbert | Thurimbert |
|
||||
| Cancor | Thurimbert,Cancor |
|
||||
| Ingramm | Thurimbert,Ingramm |
|
||||
| Ermengarde | Thurimbert,Ingramm,Ermengarde |
|
||||
| Landrade | Thurimbert,Landrade |
|
||||
| Chaudegrand | Thurimbert,Landrade,Chaudegrand |
|
||||
| Robert II | Thurimbert,Robert II |
|
||||
| Robert III | Thurimbert,Robert II,Robert III |
|
||||
+-------------+---------------------------------+
|
||||
|
||||
#Computing transitive closures with simple cycle avoidance
|
||||
|
||||
CREATE TABLE rockets
|
||||
(origin CHAR(20), destination CHAR(20), trip_time INT);
|
||||
INSERT INTO rockets VALUES
|
||||
('Earth', 'Mars', 2),
|
||||
('Mars', 'Jupiter', 3),
|
||||
('Jupiter', 'Saturn', 4);
|
||||
|
||||
WITH RECURSIVE all_destinations AS
|
||||
(
|
||||
SELECT destination AS planet
|
||||
FROM rockets
|
||||
WHERE origin='Earth'
|
||||
UNION ALL
|
||||
SELECT r.destination
|
||||
FROM rockets r, all_destinations d
|
||||
WHERE r.origin=d.planet
|
||||
)
|
||||
SELECT * FROM all_destinations;
|
||||
+---------+
|
||||
| planet |
|
||||
+---------+
|
||||
| Mars |
|
||||
| Jupiter |
|
||||
| Saturn |
|
||||
+---------+
|
||||
|
||||
INSERT INTO rockets VALUES ('Saturn', 'Earth', 9);
|
||||
|
||||
WITH RECURSIVE all_destinations AS
|
||||
(
|
||||
SELECT destination AS planet
|
||||
FROM rockets
|
||||
WHERE origin='Earth'
|
||||
UNION ALL
|
||||
SELECT r.destination
|
||||
FROM rockets r, all_destinations d
|
||||
WHERE r.origin=d.planet
|
||||
)
|
||||
SELECT * FROM all_destinations;
|
||||
ERROR 5746 (HY000): cycle detected while executing recursive WITH query
|
||||
|
||||
#More complex cycle avoidance
|
||||
|
||||
WITH RECURSIVE all_destinations AS
|
||||
(
|
||||
SELECT destination AS planet, trip_time AS total_time,
|
||||
CAST(destination AS CHAR(500)) AS path
|
||||
FROM rockets
|
||||
WHERE origin='Earth'
|
||||
UNION ALL
|
||||
SELECT r.destination, d.total_time+r.trip_time,
|
||||
CONCAT(d.path, ',', r.destination)
|
||||
FROM rockets r, all_destinations d
|
||||
WHERE r.origin=d.planet
|
||||
AND FIND_IN_SET(r.destination, d.path)=0
|
||||
)
|
||||
SELECT * FROM all_destinations;
|
||||
|
||||
+---------+------------+---------------------------+
|
||||
| planet | total_time | path |
|
||||
+---------+------------+---------------------------+
|
||||
| Mars | 2 | Mars |
|
||||
| Jupiter | 5 | Mars,Jupiter |
|
||||
| Saturn | 9 | Mars,Jupiter,Saturn |
|
||||
| Earth | 18 | Mars,Jupiter,Saturn,Earth |
|
||||
+---------+------------+---------------------------+
|
||||
|
||||
WITH RECURSIVE all_destinations AS
|
||||
(
|
||||
SELECT destination AS planet, trip_time AS total_time,
|
||||
CAST(destination AS CHAR(500)) AS path, 0 AS is_cycle
|
||||
FROM rockets
|
||||
WHERE origin='Earth'
|
||||
UNION ALL
|
||||
SELECT r.destination, d.total_time+r.trip_time,
|
||||
CONCAT(d.path, ',', r.destination),
|
||||
FIND_IN_SET(r.destination, d.path)!=0
|
||||
FROM rockets r, all_destinations d
|
||||
WHERE r.origin=d.planet
|
||||
AND is_cycle=0
|
||||
)
|
||||
SELECT * FROM all_destinations;
|
||||
+---------+------------+--------------------------------+----------+
|
||||
| planet | total_time | path | is_cycle |
|
||||
+---------+------------+--------------------------------+----------+
|
||||
| Mars | 2 | Mars | 0 |
|
||||
| Jupiter | 5 | Mars,Jupiter | 0 |
|
||||
| Saturn | 9 | Mars,Jupiter,Saturn | 0 |
|
||||
| Earth | 18 | Mars,Jupiter,Saturn,Earth | 0 |
|
||||
| Mars | 20 | Mars,Jupiter,Saturn,Earth,Mars | 1 |
|
||||
+---------+------------+--------------------------------+----------+
|
||||
|
File diff suppressed because it is too large
Load Diff
File diff suppressed because it is too large
Load Diff
File diff suppressed because it is too large
Load Diff
@ -0,0 +1,14 @@
|
||||
with cte1(c1, c2) as
|
||||
(select 1, '0' from dual
|
||||
union all select 2, '1' from dual
|
||||
),
|
||||
cte2(c1, c2) as
|
||||
(select '0', 1 from dual
|
||||
union all select cte1.c2, cte1.c1 from cte2, cte1 where 10 = cte2.c1)
|
||||
select * from cte1;
|
||||
+------+------+
|
||||
| c1 | c2 |
|
||||
+------+------+
|
||||
| 1 | 0 |
|
||||
| 2 | 1 |
|
||||
+------+------+
|
@ -0,0 +1,447 @@
|
||||
drop table EMP,DEPT,emp1,emp2;
|
||||
create table EMP (
|
||||
EMPno number,
|
||||
ENAME varchar(30),
|
||||
JOB varchar(30),
|
||||
MGR number(4),
|
||||
HIREDATE date,
|
||||
SAL number(7,2),
|
||||
COMM number(7,2),
|
||||
DEPTNO number(2)
|
||||
) ;
|
||||
|
||||
create table DEPT(
|
||||
DEPTNO number(2),
|
||||
DNAME(45),
|
||||
LOC varchar(39)
|
||||
) ;
|
||||
|
||||
CREATE TABLE emp1 (
|
||||
empno VARCHAR(4000) NOT NULL,
|
||||
ename VARCHAR(14),
|
||||
job VARCHAR(9),
|
||||
mgr VARCHAR(4000),
|
||||
hiredate DATE,
|
||||
sal NUMBER(7,2),
|
||||
comm NUMBER(7,2),
|
||||
deptno NUMBER(2));
|
||||
|
||||
CREATE TABLE emp2 (
|
||||
empno VARCHAR(4000) NOT NULL,
|
||||
ename VARCHAR(14),
|
||||
job VARCHAR(9),
|
||||
mgr VARCHAR(4000),
|
||||
hiredate DATE,
|
||||
sal NUMBER(7,2),
|
||||
comm NUMBER(7,2),
|
||||
deptno NUMBER(2));
|
||||
|
||||
insert into EMP values (7369,'SMITH','CLERK',7902, str_to_date('1980-12-17','%Y-%m-%d'),800,NULL, 20) ;
|
||||
INSERT INTO EMP VALUES (7499, 'ALLEN','SALESMAN',7698,str_to_date('1981-02-20','%Y-%m-%d'),1600,300,30) ;
|
||||
INSERT INTO EMP VALUES (7521,'WARD','SALESMAN',7698, str_to_date('1981-02-22','%Y-%m-%d'),1250, 500, 30) ;
|
||||
INSERT INTO EMP VALUES (7566,'JONES','MANAGER',7839, str_to_date('1981-08-02','%Y-%m-%d'), 2975, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES (7654,'MARTIN','SALESMAN', 7698, str_to_date('1981-09-28','%Y-%m-%d'), 1250, 1400, 30) ;
|
||||
INSERT INTO EMP VALUES (7698, 'BLAKE','MANAGER', 7839, str_to_date('1981-05-01','%Y-%m-%d'), 2850, NULL, 30) ;
|
||||
INSERT INTO EMP VALUES (7782, 'CLARK','MANAGER', 7839, str_to_date('1981-06-09','%Y-%m-%d'), 2450, NULL, 10) ;
|
||||
insert into EMP values (7788,'SCOTT','ANALYST', 7566, str_to_date('1987-08-19','%Y-%m-%d'), 3000, null, 20) ;
|
||||
INSERT INTO EMP VALUES (7839, 'KING','PRESIDENT', NULL, str_to_date('1981-11-17','%Y-%m-%d'), 5000, NULL, 10) ;
|
||||
INSERT INTO EMP VALUES (7844, 'TURNER','SALESMAN', 7698, str_to_date('1981-09-08','%Y-%m-%d'), 1500, 0, 30) ;
|
||||
INSERT INTO EMP VALUES(7876, 'ADAMS','CLERK', 7788, str_to_date('1987-05-23','%Y-%m-%d'), 1100, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES(7900, 'JAMES', 'CLEARK', 7698, str_to_date('1981-12-03','%Y-%m-%d'), 950, NULL, 30) ;
|
||||
INSERT INTO EMP VALUES(7902, 'FORD','ANALYST',7566, str_to_date('1981-12-03','%Y-%m-%d'), 3000, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES(7934,'MILLER','CLERK', 7782, str_to_date('1982-06-23','%Y-%m-%d'), 1300,NULL, 10) ;
|
||||
|
||||
|
||||
INSERT INTO emp1 values (7369, 'SMITH', 'CLERK', 7902, str_to_date('1980-12-17', '%Y-%m-%d'), 800, null, 20);
|
||||
INSERT INTO emp1 values (7499, 'ALLEN', 'SALESMAN', 7698, str_to_date('1981-02-20', '%Y-%m-%d'), 1600, 300, 30);
|
||||
INSERT INTO emp1 values (7521, 'WARD', 'SALESMAN', 7698, str_to_date('1981-02-22', '%Y-%m-%d'), 1250, 500, 30);
|
||||
INSERT INTO emp1 values (7566, 'JONES', 'MANAGER', 7839, str_to_date('1981-08-02', '%Y-%m-%d'), 2975, null, 20);
|
||||
INSERT INTO emp1 values (7654, 'MARTIN', 'SALESMAN', 7698, str_to_date('1981-09-28', '%Y-%m-%d'), 1250, 1400, 30);
|
||||
INSERT INTO emp1 values (7698, 'BLAKE', 'MANAGER', 7839, str_to_date('1981-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (7782, 'CLARK', 'MANAGER', 7839, str_to_date('1981-06-09' , '%Y-%m-%d'), 2450, null, 10);
|
||||
INSERT INTO emp1 values (7788, 'SCOTT', 'ANALYST', 7566, str_to_date('1987-08-19', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp1 values (7839, 'KING', 'PRESIDENT', null, str_to_date('1981-11-17', '%Y-%m-%d'), 5000, null, 10);
|
||||
INSERT INTO emp1 values (7844, 'TURNER', 'SALESMAN', 7698, str_to_date('1981-09-08', '%Y-%m-%d'), 1500, 0, 30);
|
||||
INSERT INTO emp1 values (7876, 'ADAMS', 'CLERK', 7788, str_to_date('1987-05-23', '%Y-%m-%d'), 1100, null, 20);
|
||||
INSERT INTO emp1 values (7900, 'JAMES', 'CLERK', 7698, str_to_date('1981-12-03', '%Y-%m-%d'), 950, null, 30);
|
||||
INSERT INTO emp1 values (7902, 'FORD', 'ANALYST', 7566, str_to_date('1981-12-03', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp1 values (7934, 'MILLER', 'CLERK', 7782, str_to_date('1982-01-23', '%Y-%m-%d'), 1300, null, 10);
|
||||
INSERT INTO emp1 values (LPAD('8100',400,'5'), 'Eve', 'MANAGER', 7839, str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8101',3000,'5'), 'Eve1', 'MANAGER', LPAD('8100',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8102',3000,'5'), 'Eve2', 'MANAGER', LPAD('8101',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8103',3000,'5'), 'Eve3', 'MANAGER', LPAD('8102',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8104',3000,'5'), 'Eve4', 'MANAGER', LPAD('8103',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8105',3000,'5'), 'Eve5', 'MANAGER', LPAD('8104',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8106',3000,'5'), 'Eve6', 'MANAGER', LPAD('8105',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8107',400,'5'), 'Eve7', 'MANAGER', LPAD('8106',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8108',400,'5'), 'Eve8', 'MANAGER', LPAD('8107',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8109',400,'5'), 'Eve9', 'MANAGER', LPAD('8108',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8110',400,'5'), 'Eve10', 'MANAGER', LPAD('8109',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8111',400,'5'), 'Eve11', 'MANAGER', LPAD('8110',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8112',400,'5'), 'Eve12', 'MANAGER', LPAD('8111',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8113',400,'5'), 'Eve13', 'MANAGER', LPAD('8112',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8114',400,'5'), 'Eve14', 'MANAGER', LPAD('8113',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8115',400,'5'), 'Eve15', 'MANAGER', LPAD('8114',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8116',400,'5'), 'Eve16', 'MANAGER', LPAD('8115',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8117',400,'5'), 'Eve17', 'MANAGER', LPAD('8116',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8118',400,'5'), 'Eve18', 'MANAGER', LPAD('8117',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8119',400,'5'), 'Eve19', 'CLERK', LPAD('8118',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
|
||||
INSERT INTO emp2 values (4002, 'SMITH', 'CLERK', 5002, str_to_date('1980-12-17', '%Y-%m-%d'), 800, null, 20);
|
||||
INSERT INTO emp2 values (5003, 'ALLEN', 'SALESMAN', 6002, str_to_date('1981-02-20', '%Y-%m-%d'), 1600, 300, 30);
|
||||
INSERT INTO emp2 values (5004, 'WARD', 'SALESMAN', 6002, str_to_date('1981-02-22', '%Y-%m-%d'), 1250, 500, 30);
|
||||
INSERT INTO emp2 values (6001, 'JONES', 'MANAGER', 7839, str_to_date('1981-08-02', '%Y-%m-%d'), 2975, null, 20);
|
||||
INSERT INTO emp2 values (5005, 'MARTIN', 'SALESMAN', 6002, str_to_date('1981-09-28', '%Y-%m-%d'), 1250, 1400, 30);
|
||||
INSERT INTO emp2 values (6002, 'BLAKE', 'MANAGER', 7839, str_to_date('1981-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp2 values (6003, 'CLARK', 'MANAGER', 7839, str_to_date('1981-06-09' , '%Y-%m-%d'), 2450, null, 10);
|
||||
INSERT INTO emp2 values (5001, 'SCOTT', 'ANALYST', 6001, str_to_date('1987-08-19', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp2 values (7839, 'KING', 'PRESIDENT', null, str_to_date('1987-11-17', '%Y-%m-%d'), 5000, null, 10);
|
||||
INSERT INTO emp2 values (5006, 'TURNER', 'SALESMAN', 6002, str_to_date('1981-09-08', '%Y-%m-%d'), 1500, 0, 30);
|
||||
INSERT INTO emp2 values (4001, 'ADAMS', 'CLERK', 5001, str_to_date('1987-05-23', '%Y-%m-%d'), 1100, null, 20);
|
||||
INSERT INTO emp2 values (5007, 'JAMES', 'CLERK', 6002, str_to_date('1981-12-03', '%Y-%m-%d'), 950, null, 30);
|
||||
INSERT INTO emp2 values (5002, 'FORD', 'ANALYST', 6001, str_to_date('1981-12-03', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp2 values (5008, 'MILLER', 'CLERK', 6003, str_to_date('1982-01-23', '%Y-%m-%d'), 1300, null, 10);
|
||||
|
||||
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 1:
|
||||
## - recursive WITH Query: no cycle clause used in query in acyclic data
|
||||
## =======================================================================
|
||||
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
+--------+-------+------+
|
||||
| ename | empno | mgr |
|
||||
+--------+-------+------+
|
||||
| KING | 7839 | NULL |
|
||||
| CLARK | 7782 | 7839 |
|
||||
| BLAKE | 7698 | 7839 |
|
||||
| JONES | 7566 | 7839 |
|
||||
| MILLER | 7934 | 7782 |
|
||||
| JAMES | 7900 | 7698 |
|
||||
| TURNER | 7844 | 7698 |
|
||||
| MARTIN | 7654 | 7698 |
|
||||
| WARD | 7521 | 7698 |
|
||||
| ALLEN | 7499 | 7698 |
|
||||
| FORD | 7902 | 7566 |
|
||||
| SCOTT | 7788 | 7566 |
|
||||
| SMITH | 7369 | 7902 |
|
||||
| ADAMS | 7876 | 7788 |
|
||||
+--------+-------+------+
|
||||
|
||||
|
||||
update emp set mgr = 7788 where ename = 'KING';
|
||||
|
||||
drop table emp1;
|
||||
drop table emp2;
|
||||
|
||||
CREATE TABLE emp1 (
|
||||
empno VARCHAR(4000) NOT NULL,
|
||||
ename VARCHAR(14),
|
||||
job VARCHAR(9),
|
||||
mgr VARCHAR(4000),
|
||||
hiredate DATE,
|
||||
sal NUMBER(7,2),
|
||||
comm NUMBER(7,2),
|
||||
deptno NUMBER(2));
|
||||
|
||||
CREATE TABLE emp2 (
|
||||
empno VARCHAR(4000) NOT NULL,
|
||||
ename VARCHAR(14),
|
||||
job VARCHAR(9),
|
||||
mgr VARCHAR(4000),
|
||||
hiredate DATE,
|
||||
sal NUMBER(7,2),
|
||||
comm NUMBER(7,2),
|
||||
deptno NUMBER(2));
|
||||
|
||||
INSERT INTO emp1 values (7369, 'SMITH', 'CLERK', 7902, str_to_date('1980-12-17', '%Y-%m-%d'), 800, null, 20);
|
||||
INSERT INTO emp1 values (7499, 'ALLEN', 'SALESMAN', 7698, str_to_date('1981-02-20', '%Y-%m-%d'), 1600, 300, 30);
|
||||
INSERT INTO emp1 values (7521, 'WARD', 'SALESMAN', 7698, str_to_date('1981-02-22', '%Y-%m-%d'), 1250, 500, 30);
|
||||
INSERT INTO emp1 values (7566, 'JONES', 'MANAGER', 7839, str_to_date('1981-08-02', '%Y-%m-%d'), 2975, null, 20);
|
||||
INSERT INTO emp1 values (7654, 'MARTIN', 'SALESMAN', 7698, str_to_date('1981-09-28', '%Y-%m-%d'), 1250, 1400, 30);
|
||||
INSERT INTO emp1 values (7698, 'BLAKE', 'MANAGER', 7839, str_to_date('1981-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (7782, 'CLARK', 'MANAGER', 7839, str_to_date('1981-06-09' , '%Y-%m-%d'), 2450, null, 10);
|
||||
INSERT INTO emp1 values (7788, 'SCOTT', 'ANALYST', 7566, str_to_date('1987-08-19', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp1 values (7839, 'KING', 'PRESIDENT', null, str_to_date('1981-11-17', '%Y-%m-%d'), 5000, null, 10);
|
||||
INSERT INTO emp1 values (7844, 'TURNER', 'SALESMAN', 7698, str_to_date('1981-09-08', '%Y-%m-%d'), 1500, 0, 30);
|
||||
INSERT INTO emp1 values (7876, 'ADAMS', 'CLERK', 7788, str_to_date('1987-05-23', '%Y-%m-%d'), 1100, null, 20);
|
||||
INSERT INTO emp1 values (7900, 'JAMES', 'CLERK', 7698, str_to_date('1981-12-03', '%Y-%m-%d'), 950, null, 30);
|
||||
INSERT INTO emp1 values (7902, 'FORD', 'ANALYST', 7566, str_to_date('1981-12-03', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp1 values (7934, 'MILLER', 'CLERK', 7782, str_to_date('1982-01-23', '%Y-%m-%d'), 1300, null, 10);
|
||||
INSERT INTO emp1 values (LPAD('8100',400,'5'), 'Eve', 'MANAGER', 7839, str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8101',3000,'5'), 'Eve1', 'MANAGER', LPAD('8100',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8102',3000,'5'), 'Eve2', 'MANAGER', LPAD('8101',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8103',3000,'5'), 'Eve3', 'MANAGER', LPAD('8102',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8104',3000,'5'), 'Eve4', 'MANAGER', LPAD('8103',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8105',3000,'5'), 'Eve5', 'MANAGER', LPAD('8104',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8106',3000,'5'), 'Eve6', 'MANAGER', LPAD('8105',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8107',400,'5'), 'Eve7', 'MANAGER', LPAD('8106',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8108',400,'5'), 'Eve8', 'MANAGER', LPAD('8107',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8109',400,'5'), 'Eve9', 'MANAGER', LPAD('8108',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8110',400,'5'), 'Eve10', 'MANAGER', LPAD('8109',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8111',400,'5'), 'Eve11', 'MANAGER', LPAD('8110',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8112',400,'5'), 'Eve12', 'MANAGER', LPAD('8111',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8113',400,'5'), 'Eve13', 'MANAGER', LPAD('8112',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8114',400,'5'), 'Eve14', 'MANAGER', LPAD('8113',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8115',400,'5'), 'Eve15', 'MANAGER', LPAD('8114',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8116',400,'5'), 'Eve16', 'MANAGER', LPAD('8115',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8117',400,'5'), 'Eve17', 'MANAGER', LPAD('8116',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8118',400,'5'), 'Eve18', 'MANAGER', LPAD('8117',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8119',400,'5'), 'Eve19', 'CLERK', LPAD('8118',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
|
||||
INSERT INTO emp2 values (4002, 'SMITH', 'CLERK', 5002, str_to_date('1980-12-17', '%Y-%m-%d'), 800, null, 20);
|
||||
INSERT INTO emp2 values (5003, 'ALLEN', 'SALESMAN', 6002, str_to_date('1981-02-20', '%Y-%m-%d'), 1600, 300, 30);
|
||||
INSERT INTO emp2 values (5004, 'WARD', 'SALESMAN', 6002, str_to_date('1981-02-22', '%Y-%m-%d'), 1250, 500, 30);
|
||||
INSERT INTO emp2 values (6001, 'JONES', 'MANAGER', 7839, str_to_date('1981-08-02', '%Y-%m-%d'), 2975, null, 20);
|
||||
INSERT INTO emp2 values (5005, 'MARTIN', 'SALESMAN', 6002, str_to_date('1981-09-28', '%Y-%m-%d'), 1250, 1400, 30);
|
||||
INSERT INTO emp2 values (6002, 'BLAKE', 'MANAGER', 7839, str_to_date('1981-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp2 values (6003, 'CLARK', 'MANAGER', 7839, str_to_date('1981-06-09' , '%Y-%m-%d'), 2450, null, 10);
|
||||
INSERT INTO emp2 values (5001, 'SCOTT', 'ANALYST', 6001, str_to_date('1987-08-19', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp2 values (7839, 'KING', 'PRESIDENT', null, str_to_date('1987-11-17', '%Y-%m-%d'), 5000, null, 10);
|
||||
INSERT INTO emp2 values (5006, 'TURNER', 'SALESMAN', 6002, str_to_date('1981-09-08', '%Y-%m-%d'), 1500, 0, 30);
|
||||
INSERT INTO emp2 values (4001, 'ADAMS', 'CLERK', 5001, str_to_date('1987-05-23', '%Y-%m-%d'), 1100, null, 20);
|
||||
INSERT INTO emp2 values (5007, 'JAMES', 'CLERK', 6002, str_to_date('1981-12-03', '%Y-%m-%d'), 950, null, 30);
|
||||
INSERT INTO emp2 values (5002, 'FORD', 'ANALYST', 6001, str_to_date('1981-12-03', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp2 values (5008, 'MILLER', 'CLERK', 6003, str_to_date('1982-01-23', '%Y-%m-%d'), 1300, null, 10);
|
||||
|
||||
--enable_warnings
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 2:
|
||||
## - recursive WITH Query(Negative): cycle clause not used in query with
|
||||
## cyclic data
|
||||
## =======================================================================
|
||||
|
||||
/* add loop from scott back to king in emp */
|
||||
update emp set mgr = 7788 where ename = 'KING';
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
ERROR 5746 (HY000): cycle detected while executing recursive WITH query
|
||||
|
||||
|
||||
drop table emp1;
|
||||
drop table emp2;
|
||||
|
||||
CREATE TABLE emp1 (
|
||||
empno VARCHAR(4000) NOT NULL,
|
||||
ename VARCHAR(14),
|
||||
job VARCHAR(9),
|
||||
mgr VARCHAR(4000),
|
||||
hiredate DATE,
|
||||
sal NUMBER(7,2),
|
||||
comm NUMBER(7,2),
|
||||
deptno NUMBER(2));
|
||||
|
||||
CREATE TABLE emp2 (
|
||||
empno VARCHAR(4000) NOT NULL,
|
||||
ename VARCHAR(14),
|
||||
job VARCHAR(9),
|
||||
mgr VARCHAR(4000),
|
||||
hiredate DATE,
|
||||
sal NUMBER(7,2),
|
||||
comm NUMBER(7,2),
|
||||
deptno NUMBER(2));
|
||||
|
||||
INSERT INTO emp1 values (7369, 'SMITH', 'CLERK', 7902, str_to_date('1980-12-17', '%Y-%m-%d'), 800, null, 20);
|
||||
INSERT INTO emp1 values (7499, 'ALLEN', 'SALESMAN', 7698, str_to_date('1981-02-20', '%Y-%m-%d'), 1600, 300, 30);
|
||||
INSERT INTO emp1 values (7521, 'WARD', 'SALESMAN', 7698, str_to_date('1981-02-22', '%Y-%m-%d'), 1250, 500, 30);
|
||||
INSERT INTO emp1 values (7566, 'JONES', 'MANAGER', 7839, str_to_date('1981-08-02', '%Y-%m-%d'), 2975, null, 20);
|
||||
INSERT INTO emp1 values (7654, 'MARTIN', 'SALESMAN', 7698, str_to_date('1981-09-28', '%Y-%m-%d'), 1250, 1400, 30);
|
||||
INSERT INTO emp1 values (7698, 'BLAKE', 'MANAGER', 7839, str_to_date('1981-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (7782, 'CLARK', 'MANAGER', 7839, str_to_date('1981-06-09' , '%Y-%m-%d'), 2450, null, 10);
|
||||
INSERT INTO emp1 values (7788, 'SCOTT', 'ANALYST', 7566, str_to_date('1987-08-19', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp1 values (7839, 'KING', 'PRESIDENT', null, str_to_date('1981-11-17', '%Y-%m-%d'), 5000, null, 10);
|
||||
INSERT INTO emp1 values (7844, 'TURNER', 'SALESMAN', 7698, str_to_date('1981-09-08', '%Y-%m-%d'), 1500, 0, 30);
|
||||
INSERT INTO emp1 values (7876, 'ADAMS', 'CLERK', 7788, str_to_date('1987-05-23', '%Y-%m-%d'), 1100, null, 20);
|
||||
INSERT INTO emp1 values (7900, 'JAMES', 'CLERK', 7698, str_to_date('1981-12-03', '%Y-%m-%d'), 950, null, 30);
|
||||
INSERT INTO emp1 values (7902, 'FORD', 'ANALYST', 7566, str_to_date('1981-12-03', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp1 values (7934, 'MILLER', 'CLERK', 7782, str_to_date('1982-01-23', '%Y-%m-%d'), 1300, null, 10);
|
||||
INSERT INTO emp1 values (LPAD('8100',400,'5'), 'Eve', 'MANAGER', 7839, str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8101',3000,'5'), 'Eve1', 'MANAGER', LPAD('8100',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8102',3000,'5'), 'Eve2', 'MANAGER', LPAD('8101',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8103',3000,'5'), 'Eve3', 'MANAGER', LPAD('8102',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8104',3000,'5'), 'Eve4', 'MANAGER', LPAD('8103',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8105',3000,'5'), 'Eve5', 'MANAGER', LPAD('8104',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8106',3000,'5'), 'Eve6', 'MANAGER', LPAD('8105',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8107',400,'5'), 'Eve7', 'MANAGER', LPAD('8106',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8108',400,'5'), 'Eve8', 'MANAGER', LPAD('8107',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8109',400,'5'), 'Eve9', 'MANAGER', LPAD('8108',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8110',400,'5'), 'Eve10', 'MANAGER', LPAD('8109',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8111',400,'5'), 'Eve11', 'MANAGER', LPAD('8110',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8112',400,'5'), 'Eve12', 'MANAGER', LPAD('8111',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8113',400,'5'), 'Eve13', 'MANAGER', LPAD('8112',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8114',400,'5'), 'Eve14', 'MANAGER', LPAD('8113',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8115',400,'5'), 'Eve15', 'MANAGER', LPAD('8114',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8116',400,'5'), 'Eve16', 'MANAGER', LPAD('8115',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8117',400,'5'), 'Eve17', 'MANAGER', LPAD('8116',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8118',400,'5'), 'Eve18', 'MANAGER', LPAD('8117',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8119',400,'5'), 'Eve19', 'CLERK', LPAD('8118',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
|
||||
INSERT INTO emp2 values (4002, 'SMITH', 'CLERK', 5002, str_to_date('1980-12-17', '%Y-%m-%d'), 800, null, 20);
|
||||
INSERT INTO emp2 values (5003, 'ALLEN', 'SALESMAN', 6002, str_to_date('1981-02-20', '%Y-%m-%d'), 1600, 300, 30);
|
||||
INSERT INTO emp2 values (5004, 'WARD', 'SALESMAN', 6002, str_to_date('1981-02-22', '%Y-%m-%d'), 1250, 500, 30);
|
||||
INSERT INTO emp2 values (6001, 'JONES', 'MANAGER', 7839, str_to_date('1981-08-02', '%Y-%m-%d'), 2975, null, 20);
|
||||
INSERT INTO emp2 values (5005, 'MARTIN', 'SALESMAN', 6002, str_to_date('1981-09-28', '%Y-%m-%d'), 1250, 1400, 30);
|
||||
INSERT INTO emp2 values (6002, 'BLAKE', 'MANAGER', 7839, str_to_date('1981-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp2 values (6003, 'CLARK', 'MANAGER', 7839, str_to_date('1981-06-09' , '%Y-%m-%d'), 2450, null, 10);
|
||||
INSERT INTO emp2 values (5001, 'SCOTT', 'ANALYST', 6001, str_to_date('1987-08-19', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp2 values (7839, 'KING', 'PRESIDENT', null, str_to_date('1987-11-17', '%Y-%m-%d'), 5000, null, 10);
|
||||
INSERT INTO emp2 values (5006, 'TURNER', 'SALESMAN', 6002, str_to_date('1981-09-08', '%Y-%m-%d'), 1500, 0, 30);
|
||||
INSERT INTO emp2 values (4001, 'ADAMS', 'CLERK', 5001, str_to_date('1987-05-23', '%Y-%m-%d'), 1100, null, 20);
|
||||
INSERT INTO emp2 values (5007, 'JAMES', 'CLERK', 6002, str_to_date('1981-12-03', '%Y-%m-%d'), 950, null, 30);
|
||||
INSERT INTO emp2 values (5002, 'FORD', 'ANALYST', 6001, str_to_date('1981-12-03', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp2 values (5008, 'MILLER', 'CLERK', 6003, str_to_date('1982-01-23', '%Y-%m-%d'), 1300, null, 10);
|
||||
|
||||
|
||||
update emp2 set mgr = 5001 where ename = 'KING';
|
||||
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 3:
|
||||
## - recursive WITH Query: Cycle Pruning with Cycle clause not used in the query
|
||||
## Pruning predicate added that results in no cycles e.mgr < e.empno
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp2 e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp2 e
|
||||
WHERE r.empno = e.mgr and e.mgr < e.empno
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
+-------+-------+------+
|
||||
| ename | empno | mgr |
|
||||
+-------+-------+------+
|
||||
| KING | 7839 | 5001 |
|
||||
+-------+-------+------+
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 4:
|
||||
## - recursive WITH Query: Cycle Pruning with Cycle clause not used in the query
|
||||
## Pruning predicate added that results in no cycles e.mgr > e.empno
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp2 e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp2 e
|
||||
WHERE r.empno = e.mgr and e.mgr > e.empno
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
+--------+-------+------+
|
||||
| ename | empno | mgr |
|
||||
+--------+-------+------+
|
||||
| KING | 7839 | 5001 |
|
||||
| CLARK | 6003 | 7839 |
|
||||
| BLAKE | 6002 | 7839 |
|
||||
| JONES | 6001 | 7839 |
|
||||
| MILLER | 5008 | 6003 |
|
||||
| JAMES | 5007 | 6002 |
|
||||
| TURNER | 5006 | 6002 |
|
||||
| MARTIN | 5005 | 6002 |
|
||||
| WARD | 5004 | 6002 |
|
||||
| ALLEN | 5003 | 6002 |
|
||||
| FORD | 5002 | 6001 |
|
||||
| SCOTT | 5001 | 6001 |
|
||||
| SMITH | 4002 | 5002 |
|
||||
| ADAMS | 4001 | 5001 |
|
||||
+--------+-------+------+
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 5:
|
||||
## - recursive WITH Query: Cycle Pruning with Cycle clause not used in the query
|
||||
## Pruning predicate added that results in no cycles r.empno < e.empno
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp2 e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp2 e
|
||||
WHERE r.empno = e.mgr and r.empno < e.empno
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
+-------+-------+------+
|
||||
| ename | empno | mgr |
|
||||
+-------+-------+------+
|
||||
| KING | 7839 | 5001 |
|
||||
+-------+-------+------+
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 6:
|
||||
## - recursive WITH Query: Cycle Pruning with Cycle clause not used in the query
|
||||
## Pruning predicate added that results in no cycles r.empno > e.empno
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp2 e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp2 e
|
||||
WHERE r.empno = e.mgr and r.empno > e.empno
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
+--------+-------+------+
|
||||
| ename | empno | mgr |
|
||||
+--------+-------+------+
|
||||
| KING | 7839 | 5001 |
|
||||
| CLARK | 6003 | 7839 |
|
||||
| BLAKE | 6002 | 7839 |
|
||||
| JONES | 6001 | 7839 |
|
||||
| MILLER | 5008 | 6003 |
|
||||
| JAMES | 5007 | 6002 |
|
||||
| TURNER | 5006 | 6002 |
|
||||
| MARTIN | 5005 | 6002 |
|
||||
| WARD | 5004 | 6002 |
|
||||
| ALLEN | 5003 | 6002 |
|
||||
| FORD | 5002 | 6001 |
|
||||
| SCOTT | 5001 | 6001 |
|
||||
| SMITH | 4002 | 5002 |
|
||||
| ADAMS | 4001 | 5001 |
|
||||
+--------+-------+------+
|
||||
|
||||
|
||||
|
||||
|
@ -0,0 +1,675 @@
|
||||
drop table EMP;
|
||||
create table EMP (
|
||||
EMPno number,
|
||||
ENAME VARCHAR(30),
|
||||
JOB VARCHAR(30),
|
||||
MGR number(4),
|
||||
HIREDATE date,
|
||||
SAL number(7,2),
|
||||
COMM number(7,2),
|
||||
DEPTNO number(2)
|
||||
) ;
|
||||
|
||||
INSERT INTO EMP values (7369,'SMITH','CLERK',7902, str_to_date('1980-12-17','%Y-%m-%d'),800,NULL, 20) ;
|
||||
INSERT INTO EMP VALUES (7499, 'ALLEN','SALESMAN',7698,str_to_date('1981-02-20','%Y-%m-%d'),1600,300,30) ;
|
||||
INSERT INTO EMP VALUES (7521,'WARD','SALESMAN',7698, str_to_date('1981-02-22','%Y-%m-%d'),1250, 500, 30) ;
|
||||
INSERT INTO EMP VALUES (7566,'JONES','MANAGER',7839, str_to_date('1981-08-02','%Y-%m-%d'), 2975, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES (7654,'MARTIN','SALESMAN', 7698, str_to_date('1981-09-28','%Y-%m-%d'), 1250, 1400, 30) ;
|
||||
INSERT INTO EMP VALUES (7698, 'BLAKE','MANAGER', 7839, str_to_date('1981-05-01','%Y-%m-%d'), 2850, NULL, 30) ;
|
||||
INSERT INTO EMP VALUES (7782, 'CLARK','MANAGER', 7839, str_to_date('1981-06-09','%Y-%m-%d'), 2450, NULL, 10) ;
|
||||
insert into EMP values (7788,'SCOTT','ANALYST', 7566, str_to_date('1987-08-19','%Y-%m-%d'), 3000, null, 20) ;
|
||||
INSERT INTO EMP VALUES (7839, 'KING','PRESIDENT', NULL, str_to_date('1981-11-17','%Y-%m-%d'), 5000, NULL, 10) ;
|
||||
INSERT INTO EMP VALUES (7844, 'TURNER','SALESMAN', 7698, str_to_date('1981-09-08','%Y-%m-%d'), 1500, 0, 30) ;
|
||||
INSERT INTO EMP VALUES(7876, 'ADAMS','CLERK', 7788, str_to_date('1987-05-23','%Y-%m-%d'), 1100, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES(7900, 'JAMES', 'CLEARK', 7698, str_to_date('1981-12-03','%Y-%m-%d'), 950, NULL, 30) ;
|
||||
INSERT INTO EMP VALUES(7902, 'FORD','ANALYST',7566, str_to_date('1981-12-03','%Y-%m-%d'), 3000, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES(7934,'MILLER','CLERK', 7782, str_to_date('1982-01-23','%Y-%m-%d'), 1300,NULL, 10) ;
|
||||
|
||||
drop table emp1;
|
||||
CREATE TABLE emp1 (
|
||||
empno VARCHAR(4000) NOT NULL,
|
||||
ename VARCHAR(14),
|
||||
job VARCHAR(9),
|
||||
mgr VARCHAR(4000),
|
||||
hiredate DATE,
|
||||
sal NUMBER(7,2),
|
||||
comm NUMBER(7,2),
|
||||
deptno NUMBER(2));
|
||||
|
||||
INSERT INTO emp1 values (7369, 'SMITH', 'CLERK', 7902, str_to_date('1980-12-17',
|
||||
'%Y-%m-%d'), 800, null, 20);
|
||||
INSERT INTO emp1 values (7499, 'ALLEN', 'SALESMAN', 7698, str_to_date('1981-02-20', '%Y-%m-%d'), 1600, 300, 30);
|
||||
INSERT INTO emp1 values (7521, 'WARD', 'SALESMAN', 7698, str_to_date('1981-02-22',
|
||||
'%Y-%m-%d'), 1250, 500, 30);
|
||||
INSERT INTO emp1 values (7566, 'JONES', 'MANAGER', 7839, str_to_date('1981-08-02',
|
||||
'%Y-%m-%d'), 2975, null, 20);
|
||||
INSERT INTO emp1 values (7654, 'MARTIN', 'SALESMAN', 7698, str_to_date('1981-09-28', '%Y-%m-%d'), 1250, 1400, 30);
|
||||
INSERT INTO emp1 values (7698, 'BLAKE', 'MANAGER', 7839, str_to_date('1981-05-01',
|
||||
'%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (7782, 'CLARK', 'MANAGER', 7839, str_to_date('1981-06-09'
|
||||
, '%Y-%m-%d'), 2450, null, 10);
|
||||
INSERT INTO emp1 values (7788, 'SCOTT', 'ANALYST', 7566, str_to_date('1987-08-19',
|
||||
'%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp1 values (7839, 'KING', 'PRESIDENT', null, str_to_date('1981-11-17', '%Y-%m-%d'), 5000, null, 10);
|
||||
INSERT INTO emp1 values (7844, 'TURNER', 'SALESMAN', 7698, str_to_date('1981-09-08', '%Y-%m-%d'), 1500, 0, 30);
|
||||
INSERT INTO emp1 values (7876, 'ADAMS', 'CLERK', 7788, str_to_date('1987-05-23',
|
||||
'%Y-%m-%d'), 1100, null, 20);
|
||||
INSERT INTO emp1 values (7900, 'JAMES', 'CLERK', 7698, str_to_date('1981-12-03',
|
||||
'%Y-%m-%d'), 950, null, 30);
|
||||
INSERT INTO emp1 values (7902, 'FORD', 'ANALYST', 7566, str_to_date('1981-12-03',
|
||||
'%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp1 values (7934, 'MILLER', 'CLERK', 7782, str_to_date('1982-01-23',
|
||||
'%Y-%m-%d'), 1300, null, 10);
|
||||
|
||||
INSERT INTO emp1 values (8100, 'Eve', 'MANAGER', 7839, str_to_date('1984-05-01',
|
||||
'%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (8101, 'Eve1', 'MANAGER', 8100, str_to_date('1984-05-01',
|
||||
'%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (8108, 'Eve8', 'CLERK', 8101, str_to_date('1984-05-01',
|
||||
'%Y-%m-%d'), 2850, null, 30);
|
||||
|
||||
result_format: 4
|
||||
## =======================================================================
|
||||
## Test Case 1:
|
||||
## - recursive WITH Query: Nested Loop Join
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ USE_NL(r e) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
+--------+-------+------+
|
||||
| ename | empno | mgr |
|
||||
+--------+-------+------+
|
||||
| KING | 7839 | NULL |
|
||||
| CLARK | 7782 | 7839 |
|
||||
| BLAKE | 7698 | 7839 |
|
||||
| JONES | 7566 | 7839 |
|
||||
| MILLER | 7934 | 7782 |
|
||||
| JAMES | 7900 | 7698 |
|
||||
| TURNER | 7844 | 7698 |
|
||||
| MARTIN | 7654 | 7698 |
|
||||
| WARD | 7521 | 7698 |
|
||||
| ALLEN | 7499 | 7698 |
|
||||
| FORD | 7902 | 7566 |
|
||||
| SCOTT | 7788 | 7566 |
|
||||
| SMITH | 7369 | 7902 |
|
||||
| ADAMS | 7876 | 7788 |
|
||||
+--------+-------+------+
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 2:
|
||||
## - recursive WITH Query: SORT MERGE Join
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ USE_MERGE(r e) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
+--------+-------+------+
|
||||
| ename | empno | mgr |
|
||||
+--------+-------+------+
|
||||
| KING | 7839 | NULL |
|
||||
| CLARK | 7782 | 7839 |
|
||||
| BLAKE | 7698 | 7839 |
|
||||
| JONES | 7566 | 7839 |
|
||||
| MILLER | 7934 | 7782 |
|
||||
| JAMES | 7900 | 7698 |
|
||||
| TURNER | 7844 | 7698 |
|
||||
| MARTIN | 7654 | 7698 |
|
||||
| WARD | 7521 | 7698 |
|
||||
| ALLEN | 7499 | 7698 |
|
||||
| FORD | 7902 | 7566 |
|
||||
| SCOTT | 7788 | 7566 |
|
||||
| SMITH | 7369 | 7902 |
|
||||
| ADAMS | 7876 | 7788 |
|
||||
+--------+-------+------+
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 3:
|
||||
## - recursive WITH Query: Hash Join
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ USE_HASH(r e) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
+--------+-------+------+
|
||||
| ename | empno | mgr |
|
||||
+--------+-------+------+
|
||||
| KING | 7839 | NULL |
|
||||
| CLARK | 7782 | 7839 |
|
||||
| BLAKE | 7698 | 7839 |
|
||||
| JONES | 7566 | 7839 |
|
||||
| MILLER | 7934 | 7782 |
|
||||
| JAMES | 7900 | 7698 |
|
||||
| TURNER | 7844 | 7698 |
|
||||
| MARTIN | 7654 | 7698 |
|
||||
| WARD | 7521 | 7698 |
|
||||
| ALLEN | 7499 | 7698 |
|
||||
| FORD | 7902 | 7566 |
|
||||
| SCOTT | 7788 | 7566 |
|
||||
| SMITH | 7369 | 7902 |
|
||||
| ADAMS | 7876 | 7788 |
|
||||
+--------+-------+------+
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 4:
|
||||
## - recursive WITH Query: Join in Initialisation Branch
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT /*+ USE_NL(e d) */ e.ename, e.mgr, e.empno
|
||||
FROM emp e, emp d
|
||||
WHERE e.sal = d. sal
|
||||
UNION ALL
|
||||
SELECT /*+ USE_HASH(r e) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e, emp d
|
||||
WHERE r.empno = e.mgr and e.sal = d.sal
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
+--------+-------+------+
|
||||
| ename | empno | mgr |
|
||||
+--------+-------+------+
|
||||
| SMITH | 7369 | 7902 |
|
||||
| ALLEN | 7499 | 7698 |
|
||||
| WARD | 7521 | 7698 |
|
||||
| WARD | 7521 | 7698 |
|
||||
| JONES | 7566 | 7839 |
|
||||
| MARTIN | 7654 | 7698 |
|
||||
| MARTIN | 7654 | 7698 |
|
||||
| BLAKE | 7698 | 7839 |
|
||||
| CLARK | 7782 | 7839 |
|
||||
| SCOTT | 7788 | 7566 |
|
||||
| SCOTT | 7788 | 7566 |
|
||||
| KING | 7839 | NULL |
|
||||
| TURNER | 7844 | 7698 |
|
||||
| ADAMS | 7876 | 7788 |
|
||||
| JAMES | 7900 | 7698 |
|
||||
| FORD | 7902 | 7566 |
|
||||
| FORD | 7902 | 7566 |
|
||||
| MILLER | 7934 | 7782 |
|
||||
| WARD | 7521 | 7698 |
|
||||
| SMITH | 7369 | 7902 |
|
||||
| SMITH | 7369 | 7902 |
|
||||
| JONES | 7566 | 7839 |
|
||||
| BLAKE | 7698 | 7839 |
|
||||
| CLARK | 7782 | 7839 |
|
||||
| ADAMS | 7876 | 7788 |
|
||||
| ADAMS | 7876 | 7788 |
|
||||
| MILLER | 7934 | 7782 |
|
||||
| ALLEN | 7499 | 7698 |
|
||||
| FORD | 7902 | 7566 |
|
||||
| WARD | 7521 | 7698 |
|
||||
| MARTIN | 7654 | 7698 |
|
||||
| MARTIN | 7654 | 7698 |
|
||||
| TURNER | 7844 | 7698 |
|
||||
| JAMES | 7900 | 7698 |
|
||||
| SCOTT | 7788 | 7566 |
|
||||
| SCOTT | 7788 | 7566 |
|
||||
| FORD | 7902 | 7566 |
|
||||
| FORD | 7902 | 7566 |
|
||||
| FORD | 7902 | 7566 |
|
||||
| SCOTT | 7788 | 7566 |
|
||||
| SCOTT | 7788 | 7566 |
|
||||
| JAMES | 7900 | 7698 |
|
||||
| TURNER | 7844 | 7698 |
|
||||
| MARTIN | 7654 | 7698 |
|
||||
| MARTIN | 7654 | 7698 |
|
||||
| WARD | 7521 | 7698 |
|
||||
| WARD | 7521 | 7698 |
|
||||
| ALLEN | 7499 | 7698 |
|
||||
| MILLER | 7934 | 7782 |
|
||||
| SMITH | 7369 | 7902 |
|
||||
| ADAMS | 7876 | 7788 |
|
||||
| ADAMS | 7876 | 7788 |
|
||||
| SMITH | 7369 | 7902 |
|
||||
| SMITH | 7369 | 7902 |
|
||||
| SMITH | 7369 | 7902 |
|
||||
| ADAMS | 7876 | 7788 |
|
||||
| ADAMS | 7876 | 7788 |
|
||||
+--------+-------+------+
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 6:
|
||||
## - recursive WITH Query: Hash Join without using hints
|
||||
## Static input on build side and fits in memory
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno
|
||||
FROM emp e, rw r
|
||||
WHERE e.mgr = r.empno
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
+--------+-------+------+
|
||||
| ename | empno | mgr |
|
||||
+--------+-------+------+
|
||||
| KING | 7839 | NULL |
|
||||
| CLARK | 7782 | 7839 |
|
||||
| BLAKE | 7698 | 7839 |
|
||||
| JONES | 7566 | 7839 |
|
||||
| MILLER | 7934 | 7782 |
|
||||
| JAMES | 7900 | 7698 |
|
||||
| TURNER | 7844 | 7698 |
|
||||
| MARTIN | 7654 | 7698 |
|
||||
| WARD | 7521 | 7698 |
|
||||
| ALLEN | 7499 | 7698 |
|
||||
| FORD | 7902 | 7566 |
|
||||
| SCOTT | 7788 | 7566 |
|
||||
| SMITH | 7369 | 7902 |
|
||||
| ADAMS | 7876 | 7788 |
|
||||
+--------+-------+------+
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 7:
|
||||
## - recursive WITH Query: Hash Join without using hints
|
||||
## Static input on probe side and fits in memory
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
+--------+-------+------+
|
||||
| ename | empno | mgr |
|
||||
+--------+-------+------+
|
||||
| KING | 7839 | NULL |
|
||||
| CLARK | 7782 | 7839 |
|
||||
| BLAKE | 7698 | 7839 |
|
||||
| JONES | 7566 | 7839 |
|
||||
| MILLER | 7934 | 7782 |
|
||||
| JAMES | 7900 | 7698 |
|
||||
| TURNER | 7844 | 7698 |
|
||||
| MARTIN | 7654 | 7698 |
|
||||
| WARD | 7521 | 7698 |
|
||||
| ALLEN | 7499 | 7698 |
|
||||
| FORD | 7902 | 7566 |
|
||||
| SCOTT | 7788 | 7566 |
|
||||
| SMITH | 7369 | 7902 |
|
||||
| ADAMS | 7876 | 7788 |
|
||||
+--------+-------+------+
|
||||
|
||||
## =======================================================================
|
||||
## 测试8-15都是在测试join的顺序或者hint的顺序
|
||||
## Test Case 8:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## pump >< emp >< emp1
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (empno, mgr, iters, sal) AS
|
||||
(
|
||||
SELECT e.empno, e.mgr, 1, e.sal
|
||||
FROM emp e, emp1 n1, emp1 n2
|
||||
WHERE e.empno = n1.empno and e.mgr = n2.empno and e.empno < e.mgr
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */r.empno, e.mgr, r.iters + 1, r.sal + e.sal
|
||||
FROM rw r, emp e, emp1 n
|
||||
WHERE r.mgr = e.empno and e.mgr = n.empno and e.empno < e.mgr
|
||||
)
|
||||
SELECT *
|
||||
FROM rw
|
||||
ORDER BY 1, 3;
|
||||
+-------+------+-------+---------+
|
||||
| empno | mgr | iters | sal |
|
||||
+-------+------+-------+---------+
|
||||
| 7369 | 7902 | 1 | 800.00 |
|
||||
| 7499 | 7698 | 1 | 1600.00 |
|
||||
| 7499 | 7839 | 2 | 4450.00 |
|
||||
| 7521 | 7698 | 1 | 1250.00 |
|
||||
| 7521 | 7839 | 2 | 4100.00 |
|
||||
| 7566 | 7839 | 1 | 2975.00 |
|
||||
| 7654 | 7698 | 1 | 1250.00 |
|
||||
| 7654 | 7839 | 2 | 4100.00 |
|
||||
| 7698 | 7839 | 1 | 2850.00 |
|
||||
| 7782 | 7839 | 1 | 2450.00 |
|
||||
+-------+------+-------+---------+
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 9:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## emp >< pump >< emp1
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (empno, mgr, iters, sal) AS
|
||||
(
|
||||
SELECT e.empno, e.mgr, 1, e.sal
|
||||
FROM emp e, emp1 n1, emp1 n2
|
||||
WHERE e.empno = n1.empno and e.mgr = n2.empno and e.empno < e.mgr
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */r.empno, e.mgr, r.iters + 1, r.sal + e.sal
|
||||
FROM emp e, rw r, emp1 n
|
||||
WHERE e.empno = r.mgr and e.mgr = n.empno and e.empno < e.mgr
|
||||
)
|
||||
SELECT *
|
||||
FROM rw
|
||||
ORDER BY 1, 3;
|
||||
+-------+------+-------+---------+
|
||||
| empno | mgr | iters | sal |
|
||||
+-------+------+-------+---------+
|
||||
| 7369 | 7902 | 1 | 800.00 |
|
||||
| 7499 | 7698 | 1 | 1600.00 |
|
||||
| 7499 | 7839 | 2 | 4450.00 |
|
||||
| 7521 | 7698 | 1 | 1250.00 |
|
||||
| 7521 | 7839 | 2 | 4100.00 |
|
||||
| 7566 | 7839 | 1 | 2975.00 |
|
||||
| 7654 | 7698 | 1 | 1250.00 |
|
||||
| 7654 | 7839 | 2 | 4100.00 |
|
||||
| 7698 | 7839 | 1 | 2850.00 |
|
||||
| 7782 | 7839 | 1 | 2450.00 |
|
||||
+-------+------+-------+---------+
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 10:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## emp >< emp1 >< pump
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (empno, mgr, iters, sal) AS
|
||||
(
|
||||
SELECT e.empno, e.mgr, 1, e.sal
|
||||
FROM emp e, emp1 n1, emp1 n2
|
||||
WHERE e.empno = n1.empno and e.mgr = n2.empno and e.empno < e.mgr
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */r.empno, e.mgr, r.iters + 1, r.sal + e.sal
|
||||
FROM emp e, emp1 n, rw r
|
||||
WHERE e.mgr = n.empno and e.empno = r.mgr and e.empno < e.mgr
|
||||
)
|
||||
SELECT *
|
||||
FROM rw
|
||||
ORDER BY 1, 3;
|
||||
+-------+------+-------+---------+
|
||||
| empno | mgr | iters | sal |
|
||||
+-------+------+-------+---------+
|
||||
| 7369 | 7902 | 1 | 800.00 |
|
||||
| 7499 | 7698 | 1 | 1600.00 |
|
||||
| 7499 | 7839 | 2 | 4450.00 |
|
||||
| 7521 | 7698 | 1 | 1250.00 |
|
||||
| 7521 | 7839 | 2 | 4100.00 |
|
||||
| 7566 | 7839 | 1 | 2975.00 |
|
||||
| 7654 | 7698 | 1 | 1250.00 |
|
||||
| 7654 | 7839 | 2 | 4100.00 |
|
||||
| 7698 | 7839 | 1 | 2850.00 |
|
||||
| 7782 | 7839 | 1 | 2450.00 |
|
||||
+-------+------+-------+---------+
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 11:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## emp1 >< emp >< pump
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (empno, mgr, iters, sal) AS
|
||||
(
|
||||
SELECT e.empno, e.mgr, 1, e.sal
|
||||
FROM emp e, emp1 n1, emp1 n2
|
||||
WHERE e.empno = n1.empno and e.mgr = n2.empno and e.empno < e.mgr
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */r.empno, e.mgr, r.iters + 1, r.sal + e.sal
|
||||
FROM emp1 n, emp e, rw r
|
||||
WHERE n.empno = e.mgr and e.empno = r.mgr and e.empno < e.mgr
|
||||
)
|
||||
SELECT *
|
||||
FROM rw
|
||||
ORDER BY 1, 3;
|
||||
+-------+------+-------+---------+
|
||||
| empno | mgr | iters | sal |
|
||||
+-------+------+-------+---------+
|
||||
| 7369 | 7902 | 1 | 800.00 |
|
||||
| 7499 | 7698 | 1 | 1600.00 |
|
||||
| 7499 | 7839 | 2 | 4450.00 |
|
||||
| 7521 | 7698 | 1 | 1250.00 |
|
||||
| 7521 | 7839 | 2 | 4100.00 |
|
||||
| 7566 | 7839 | 1 | 2975.00 |
|
||||
| 7654 | 7698 | 1 | 1250.00 |
|
||||
| 7654 | 7839 | 2 | 4100.00 |
|
||||
| 7698 | 7839 | 1 | 2850.00 |
|
||||
| 7782 | 7839 | 1 | 2450.00 |
|
||||
+-------+------+-------+---------+
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 12:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## pump >< emp
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
+--------+-------+------+
|
||||
| ename | empno | mgr |
|
||||
+--------+-------+------+
|
||||
| KING | 7839 | NULL |
|
||||
| CLARK | 7782 | 7839 |
|
||||
| BLAKE | 7698 | 7839 |
|
||||
| JONES | 7566 | 7839 |
|
||||
| MILLER | 7934 | 7782 |
|
||||
| JAMES | 7900 | 7698 |
|
||||
| TURNER | 7844 | 7698 |
|
||||
| MARTIN | 7654 | 7698 |
|
||||
| WARD | 7521 | 7698 |
|
||||
| ALLEN | 7499 | 7698 |
|
||||
| FORD | 7902 | 7566 |
|
||||
| SCOTT | 7788 | 7566 |
|
||||
| SMITH | 7369 | 7902 |
|
||||
| ADAMS | 7876 | 7788 |
|
||||
+--------+-------+------+
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 13:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## emp >< pump
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */ e.ename, e.mgr, e.empno
|
||||
FROM emp e, rw r
|
||||
WHERE e.mgr = r.empno
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
+--------+-------+------+
|
||||
| ename | empno | mgr |
|
||||
+--------+-------+------+
|
||||
| KING | 7839 | NULL |
|
||||
| CLARK | 7782 | 7839 |
|
||||
| BLAKE | 7698 | 7839 |
|
||||
| JONES | 7566 | 7839 |
|
||||
| MILLER | 7934 | 7782 |
|
||||
| JAMES | 7900 | 7698 |
|
||||
| TURNER | 7844 | 7698 |
|
||||
| MARTIN | 7654 | 7698 |
|
||||
| WARD | 7521 | 7698 |
|
||||
| ALLEN | 7499 | 7698 |
|
||||
| FORD | 7902 | 7566 |
|
||||
| SCOTT | 7788 | 7566 |
|
||||
| SMITH | 7369 | 7902 |
|
||||
| ADAMS | 7876 | 7788 |
|
||||
+--------+-------+------+
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 14:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## emp1 >< pump >< emp
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (empno, mgr, iters, sal) AS
|
||||
(
|
||||
SELECT e.empno, e.mgr, 1, e.sal
|
||||
FROM emp e, emp1 n1, emp1 n2
|
||||
WHERE e.empno = n1.empno and e.mgr = n2.empno and e.empno < e.mgr
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */r.empno, e.mgr, r.iters + 1, r.sal + e.sal
|
||||
FROM emp1 n, rw r, emp e
|
||||
WHERE n.empno = e.mgr and r.mgr = e.empno and e.empno < e.mgr
|
||||
)
|
||||
SELECT *
|
||||
FROM rw
|
||||
ORDER BY 1, 3;
|
||||
+-------+------+-------+---------+
|
||||
| empno | mgr | iters | sal |
|
||||
+-------+------+-------+---------+
|
||||
| 7369 | 7902 | 1 | 800.00 |
|
||||
| 7499 | 7698 | 1 | 1600.00 |
|
||||
| 7499 | 7839 | 2 | 4450.00 |
|
||||
| 7521 | 7698 | 1 | 1250.00 |
|
||||
| 7521 | 7839 | 2 | 4100.00 |
|
||||
| 7566 | 7839 | 1 | 2975.00 |
|
||||
| 7654 | 7698 | 1 | 1250.00 |
|
||||
| 7654 | 7839 | 2 | 4100.00 |
|
||||
| 7698 | 7839 | 1 | 2850.00 |
|
||||
| 7782 | 7839 | 1 | 2450.00 |
|
||||
+-------+------+-------+---------+
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 15:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## pump >< emp1 >< emp
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (empno, mgr, iters, sal) AS
|
||||
(
|
||||
SELECT e.empno, e.mgr, 1, e.sal
|
||||
FROM emp e, emp1 n1, emp1 n2
|
||||
WHERE e.empno = n1.empno and e.mgr = n2.empno and e.empno < e.mgr
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */r.empno, e.mgr, r.iters + 1, r.sal + e.sal
|
||||
FROM rw r, emp1 n, emp e
|
||||
WHERE r.mgr = e.empno and n.empno = e.mgr and e.empno < e.mgr
|
||||
)
|
||||
SELECT *
|
||||
FROM rw
|
||||
ORDER BY 1, 3;
|
||||
+-------+------+-------+---------+
|
||||
| empno | mgr | iters | sal |
|
||||
+-------+------+-------+---------+
|
||||
| 7369 | 7902 | 1 | 800.00 |
|
||||
| 7499 | 7698 | 1 | 1600.00 |
|
||||
| 7499 | 7839 | 2 | 4450.00 |
|
||||
| 7521 | 7698 | 1 | 1250.00 |
|
||||
| 7521 | 7839 | 2 | 4100.00 |
|
||||
| 7566 | 7839 | 1 | 2975.00 |
|
||||
| 7654 | 7698 | 1 | 1250.00 |
|
||||
| 7654 | 7839 | 2 | 4100.00 |
|
||||
| 7698 | 7839 | 1 | 2850.00 |
|
||||
| 7782 | 7839 | 1 | 2450.00 |
|
||||
+-------+------+-------+---------+
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 16:
|
||||
## - recursive WITH Query: Join Skew handling. No local filter
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ PQ_SKEW (r) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
+--------+-------+------+
|
||||
| ename | empno | mgr |
|
||||
+--------+-------+------+
|
||||
| KING | 7839 | NULL |
|
||||
| CLARK | 7782 | 7839 |
|
||||
| BLAKE | 7698 | 7839 |
|
||||
| JONES | 7566 | 7839 |
|
||||
| MILLER | 7934 | 7782 |
|
||||
| JAMES | 7900 | 7698 |
|
||||
| TURNER | 7844 | 7698 |
|
||||
| MARTIN | 7654 | 7698 |
|
||||
| WARD | 7521 | 7698 |
|
||||
| ALLEN | 7499 | 7698 |
|
||||
| FORD | 7902 | 7566 |
|
||||
| SCOTT | 7788 | 7566 |
|
||||
| SMITH | 7369 | 7902 |
|
||||
| ADAMS | 7876 | 7788 |
|
||||
+--------+-------+------+
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 17:
|
||||
## - recursive WITH Query: Join Skew handling with an additional local filter
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ PQ_SKEW (r) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr and e.empno < e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
+--------+-------+------+
|
||||
| ename | empno | mgr |
|
||||
+--------+-------+------+
|
||||
| KING | 7839 | NULL |
|
||||
| CLARK | 7782 | 7839 |
|
||||
| BLAKE | 7698 | 7839 |
|
||||
| JONES | 7566 | 7839 |
|
||||
| MARTIN | 7654 | 7698 |
|
||||
| WARD | 7521 | 7698 |
|
||||
| ALLEN | 7499 | 7698 |
|
||||
+--------+-------+------+
|
File diff suppressed because it is too large
Load Diff
@ -0,0 +1,102 @@
|
||||
drop database if exists ctetest;
|
||||
create database ctetest;
|
||||
use ctetest;
|
||||
create table EMP (
|
||||
EMPno number,
|
||||
ENAME varchar(30),
|
||||
JOB varchar(30),
|
||||
MGR number(4),
|
||||
HIREDATE date,
|
||||
SAL number(7,2),
|
||||
COMM number(7,2),
|
||||
DEPTNO number(2)
|
||||
) ;
|
||||
create table DEPT(
|
||||
DEPTNO number(2),
|
||||
DNAME char(45),
|
||||
LOC varchar(39)
|
||||
) ;
|
||||
insert into EMP values (7369,'SMITH','CLERK',7902, str_to_date('17-DEC-80','%d-%b-%Y'),800,NULL, 20) ;
|
||||
INSERT INTO EMP VALUES (7499, 'ALLEN','SALESMAN',7698,str_to_date('20-FEB-81','%d-%b-%Y'),1600,300,30) ;
|
||||
INSERT INTO EMP VALUES (7521,'WARD','SALESMAN',7698, str_to_date('22-FEB-81','%d-%b-%Y'),1250, 500, 30) ;
|
||||
INSERT INTO EMP VALUES (7566,'JONES','MANAGER',7839, str_to_date('02-APR-81','%d-%b-%Y'), 2975, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES (7654,'MARTIN','SALESMAN', 7698, str_to_date('28-SEP-81','%d-%b-%Y'), 1250, 1400, 30) ;
|
||||
INSERT INTO EMP VALUES (7698, 'BLAKE','MANAGER', 7839, str_to_date('01-MAY-81','%d-%b-%Y'), 2850, NULL, 30) ;
|
||||
INSERT INTO EMP VALUES (7782, 'CLARK','MANAGER', 7839, str_to_date('09-JUN-81','%d-%b-%Y'), 2450, NULL, 10) ;
|
||||
insert into EMP values (7788,'SCOTT','ANALYST', 7566, str_to_date('19-APR-87','%d-%b-%Y'), 3000, null, 20) ;
|
||||
INSERT INTO EMP VALUES (7839, 'KING','PRESIDENT', NULL, str_to_date('17-NOV-81','%d-%b-%Y'), 5000, NULL, 10) ;
|
||||
INSERT INTO EMP VALUES (7844, 'TURNER','SALESMAN', 7698, str_to_date('08-SEP-81','%d-%b-%Y'), 1500, 0, 30) ;
|
||||
INSERT INTO EMP VALUES(7876, 'ADAMS','CLERK', 7788, str_to_date('23-MAY-87','%d-%b-%Y'), 1100, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES(7900, 'JAMES', 'CLEARK', 7698, str_to_date('03-DEC-81','%d-%b-%Y'), 950, NULL, 30) ;
|
||||
INSERT INTO EMP VALUES(7902, 'FORD','ANALYST',7566, str_to_date('03-DEC-81','%d-%b-%Y'), 3000, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES(7934,'MILLER','CLERK', 7782, str_to_date('23-JAN-82','%d-%b-%Y'), 1300,NULL, 10) ;
|
||||
result_format: 4
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 1:
|
||||
## - recursive WITH Query: Optimization on query with outside filter.
|
||||
## Predicate pushdown optimization on static value job.
|
||||
## The plan should reflect optimization or development can provide
|
||||
## parameter to show that pushdown optimization happened for init branch
|
||||
## =======================================================================
|
||||
explain basic
|
||||
WITH rw (ename, mgr, empno, job) AS
|
||||
(
|
||||
SELECT ename, mgr, empno, job
|
||||
FROM emp e
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno, e.job
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr, job
|
||||
FROM rw
|
||||
WHERE job = 'PRESIDENT' ;
|
||||
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
|
||||
| Query Plan |
|
||||
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
|
||||
| ==============================
|
||||
|ID|OPERATOR |NAME|
|
||||
------------------------------
|
||||
|0 |SUBPLAN SCAN |rw |
|
||||
|1 | RECURSIVE UNION ALL| |
|
||||
|2 | TABLE SCAN |e |
|
||||
|3 | HASH JOIN | |
|
||||
|4 | TABLE SCAN |e |
|
||||
|5 | TABLE SCAN |r |
|
||||
==============================
|
||||
|
||||
Outputs & filters:
|
||||
-------------------------------------
|
||||
0 - output([rw.ename], [rw.empno], [rw.mgr], [rw.job]), filter([rw.job = 'PRESIDENT']),
|
||||
access([rw.job], [rw.ename], [rw.empno], [rw.mgr])
|
||||
1 - output([UNION([1])], [UNION([2])], [UNION([3])], [UNION([4])]), filter(nil)
|
||||
2 - output([e.ENAME], [e.MGR], [e.EMPno], [e.JOB]), filter(nil),
|
||||
access([e.ENAME], [e.MGR], [e.EMPno], [e.JOB]), partitions(p0)
|
||||
3 - output([e.ENAME], [e.MGR], [e.EMPno], [e.JOB]), filter(nil),
|
||||
equal_conds([r.empno = e.MGR]), other_conds(nil)
|
||||
4 - output([e.MGR], [e.ENAME], [e.EMPno], [e.JOB]), filter(nil),
|
||||
access([e.MGR], [e.ENAME], [e.EMPno], [e.JOB]), partitions(p0)
|
||||
5 - output([r.empno]), filter(nil),
|
||||
access([r.empno]), partitions(nil)
|
||||
|
|
||||
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
|
||||
|
||||
WITH rw (ename, mgr, empno, job) AS
|
||||
(
|
||||
SELECT ename, mgr, empno, job
|
||||
FROM emp e
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno, e.job
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT /*+ :HINT: */ ename, empno, mgr, job
|
||||
FROM rw
|
||||
WHERE job = 'PRESIDENT' ;
|
||||
+-------+-------+------+-----------+
|
||||
| ename | empno | mgr | job |
|
||||
+-------+-------+------+-----------+
|
||||
| KING | 7839 | NULL | PRESIDENT |
|
||||
+-------+-------+------+-----------+
|
||||
|
748
test/mysql_test/test_suite/with_clause/t/basic_mysql.test
Normal file
748
test/mysql_test/test_suite/with_clause/t/basic_mysql.test
Normal file
@ -0,0 +1,748 @@
|
||||
drop table t1;
|
||||
drop table t2;
|
||||
drop table t3;
|
||||
drop table t4;
|
||||
drop table t5;
|
||||
drop table emp;
|
||||
|
||||
create table t1(c1 int, c2 int, c3 int);
|
||||
insert into t1 values(1, 2, 3);
|
||||
insert into t1 values(4, 5, 6);
|
||||
insert into t1 values(7, 8, 9);
|
||||
insert into t1 values(10, 11, 12);
|
||||
insert into t1 values(13, 14, 15);
|
||||
insert into t1 values(16, 17, 18);
|
||||
insert into t1 values(19, 20, 21);
|
||||
|
||||
create table t2(c21 int, c22 int, c23 int);
|
||||
insert into t2 values(1, 2, 3);
|
||||
insert into t2 values(4, 5, 6);
|
||||
insert into t2 values(7, 8, 9);
|
||||
insert into t2 values(10, 11, 12);
|
||||
insert into t2 values(13, 14, 15);
|
||||
insert into t2 values(16, 17, 18);
|
||||
insert into t2 values(19, 20, 21);
|
||||
|
||||
create table t3(c1 int primary key, c2 int) partition by hash(c1) partitions 2;
|
||||
insert into t3 values(1, 2);
|
||||
insert into t3 values(4, 5);
|
||||
insert into t3 values(7, 8);
|
||||
insert into t3 values(10, 11);
|
||||
insert into t3 values(13, 14);
|
||||
insert into t3 values(16, 17);
|
||||
|
||||
create table t4(c1 int primary key, c2 int);
|
||||
CREATE INDEX i1 ON t4(c2);
|
||||
insert into t4 values(11, 2);
|
||||
insert into t4 values(14, 5);
|
||||
insert into t4 values(17, 8);
|
||||
insert into t4 values(110, 11);
|
||||
insert into t4 values(113, 14);
|
||||
insert into t4 values(116, 17);
|
||||
|
||||
create table t5(c1 int primary key, c2 int, c3 int) partition by hash(c1) partitions 6;
|
||||
insert into t5 values(1, 2, 3);
|
||||
insert into t5 values(4, 5, 6);
|
||||
insert into t5 values(7, 8, 9);
|
||||
insert into t5 values(10, 11, 12);
|
||||
insert into t5 values(13, 14, 15);
|
||||
insert into t5 values(16, 17, 18);
|
||||
|
||||
create table emp (id int, name varchar(20), leaderid int);
|
||||
insert into emp values(1, 'A', '0');
|
||||
insert into emp values(2, 'AA', '1');
|
||||
insert into emp values(3, 'AB', '1');
|
||||
insert into emp values(4, 'ABA', '3');
|
||||
insert into emp values(5, 'AAA', '2');
|
||||
insert into emp values(6, 'ABB', '3');
|
||||
insert into emp values(7, 'AAA', '5');
|
||||
insert into emp values(8, 'AAA', '7');
|
||||
insert into emp values(9, 'AAAA', '5');
|
||||
insert into emp values(10, 'AAAB', '5');
|
||||
insert into emp values(11, 'AAAC', '5');
|
||||
insert into emp values(12, 'AAAA', '5');
|
||||
|
||||
##############################
|
||||
## section one cte定义
|
||||
## PART 1 定义表名的限制
|
||||
## PART 2 单个的定义
|
||||
## PART 3 多个定义
|
||||
## PART 4 subquery的变化
|
||||
## section two cte的使用
|
||||
## PART 1 cte出现在normal型查询语句中
|
||||
## PART 2 cte出现在set型查询语句中
|
||||
## PART 3 主查询中含有inline cte
|
||||
## PART 4 歧义语法
|
||||
## PART 5 出现方式
|
||||
## PART 6 定义列的使用
|
||||
## section three cte能够出现的句式
|
||||
## PART 1 select for update
|
||||
## PART 2 insert into
|
||||
## PART 3 update select
|
||||
## PART 4 select when
|
||||
## PART 5 delete from
|
||||
##############################
|
||||
|
||||
##############################
|
||||
## section one
|
||||
## PART 1 定义表名的限制
|
||||
##############################
|
||||
|
||||
## PART 1.1 表名,列名不能是保留关键字,可以是分保留关键字
|
||||
WITH explain as (select 1 from dual) select * from explain;
|
||||
|
||||
WITH cte(explain) as (select 1 from dual) select * from cte;
|
||||
|
||||
with cte(name) as (select 1 from dual) select * from cte;
|
||||
|
||||
## PART 1.2 允许与已有的表重名
|
||||
explain basic WITH t4 as (select 1 from dual) select * from t4;
|
||||
WITH t4 as (select 1 from dual) select * from t4;
|
||||
|
||||
##############################
|
||||
## PART 2 单个的定义
|
||||
##############################
|
||||
|
||||
## PART 2.1 定义列名重复
|
||||
with cte(a,a) as (select 1,1 from dual) select * from cte;
|
||||
|
||||
## PART 2.2.1 定义列数量与查询产生列一致或不一致
|
||||
explain basic with cte(a,b) as (select 1,1 from dual) select * from cte;
|
||||
with cte(a,b) as (select 1,1 from dual) select * from cte;
|
||||
|
||||
with cte(a,b) as (select 1 from dual) select * from cte;
|
||||
|
||||
with cte(a,b,c) as (select 1, 2, 3, 4 from dual) select * from cte;
|
||||
|
||||
## PART 2.2.2 不使用定义列使用原来的列
|
||||
with cte(a,b) as (select c1,c2 from t1) select c1 from cte;
|
||||
|
||||
##############################
|
||||
## PART 3 多个的定义
|
||||
##############################
|
||||
|
||||
## PART 3.1 前面的定义引用后面的,后面的引用前面的
|
||||
WITH
|
||||
cte1 (a, b) AS (SELECT c, d FROM cte2),
|
||||
cte2 (c, d) AS (SELECT c21, c22 FROM t2)
|
||||
SELECT b, d FROM cte1 JOIN cte2
|
||||
on cte1.a = cte2.c;
|
||||
|
||||
explain basic with
|
||||
cte1 AS (select c1 from t1),
|
||||
cte2 AS (select c1 from cte1)
|
||||
select * from cte1;
|
||||
|
||||
with
|
||||
cte1 AS (select c1 from t1),
|
||||
cte2 AS (select c1 from cte1)
|
||||
select * from cte1;
|
||||
|
||||
## PART 3.2.1 直接嵌套定义,MySQL支持这样的直接嵌套
|
||||
with
|
||||
cte1 AS (
|
||||
with cte2 AS (select c1 from t1)
|
||||
select c1 from cte2
|
||||
)
|
||||
select c1 from cte1;
|
||||
|
||||
with
|
||||
cte1 (cte1col) AS (
|
||||
with cte2 (cte2col) AS (select c1 from t1)
|
||||
select cte2col from cte2
|
||||
)
|
||||
select cte1col from cte1;
|
||||
|
||||
with
|
||||
cte1 (cte1col) AS (
|
||||
with cte2 (cte2col1, cte2col2) AS (select c1, c2 from t1)
|
||||
select cte2col2 from cte2
|
||||
)
|
||||
select cte1col from cte1;
|
||||
|
||||
## PART 3.2.2 在子查询中进行嵌套
|
||||
with cte(a) as (select * from (with cteb(a) as (select 1 from dual) select * from cteb) bac) select * from cte;
|
||||
|
||||
##############################
|
||||
## PART 4 subquery的变化
|
||||
##############################
|
||||
|
||||
## PART 4.1.0 subquery的变化
|
||||
## 带有聚合
|
||||
explain basic with cte as (select count(*) from t1) select * from cte;
|
||||
|
||||
with cte as (select count(*) from t1) select * from cte;
|
||||
|
||||
## 带有where
|
||||
explain basic with
|
||||
cte1 AS ( select c1 as col1 from t1 where c1 > 1)
|
||||
select col1 from cte1;
|
||||
|
||||
with
|
||||
cte1 AS ( select c1 as col1 from t1 where c1 > 1)
|
||||
select col1 from cte1;
|
||||
|
||||
explain basic with
|
||||
cte1 AS ( select * from t1 where c1+'1'<=3)
|
||||
select c1 from cte1;
|
||||
|
||||
with
|
||||
cte1 AS ( select * from t1 where c1+'1'<=3)
|
||||
select c1 from cte1;
|
||||
|
||||
## 带有group
|
||||
explain basic with
|
||||
cte1 AS ( select 1 as c1, 2 as c2 from t1 group by c1)
|
||||
select c1 from cte1;
|
||||
with
|
||||
cte1 AS ( select 1 as c1, 2 as c2 from t1 group by c1)
|
||||
select c1 from cte1;
|
||||
|
||||
## 带有having
|
||||
explain basic with
|
||||
cte1 AS ( select c1, c2 from t1 where t1.c1 > 2)
|
||||
select c1 from cte1;
|
||||
with
|
||||
cte1 AS ( select c1, c2 from t1 where t1.c1 > 2)
|
||||
select c1 from cte1;
|
||||
|
||||
## 带有order
|
||||
explain basic with
|
||||
cte1 AS ( select c1, c2 + 1 as c3 from t1 order by c2)
|
||||
select c1 from cte1;
|
||||
with
|
||||
cte1 AS ( select c1, c2 + 1 as c3 from t1 order by c2)
|
||||
select c1 from cte1;
|
||||
|
||||
explain basic with
|
||||
cte2 AS (select * from t1 left join t2 on t1.c1=t2.c21 order by t1.c1)
|
||||
select c1 from cte2;
|
||||
with
|
||||
cte2 AS (select * from t1 left join t2 on t1.c1=t2.c21 order by t1.c1)
|
||||
select c1 from cte2;
|
||||
|
||||
## PART 4.1.1 normal型+hint
|
||||
## index
|
||||
## use_nl/use_merge/leading
|
||||
## hint在cte定义里面
|
||||
explain basic with
|
||||
cte0 AS (select /*+ use_nl(t1 t2) */ * from t2, t1 where t1.c1 = t2.c21)
|
||||
select * from cte0;
|
||||
|
||||
with
|
||||
cte0 AS (select /*+ use_nl(t1 t2) */ * from t2, t1 where t1.c1 = t2.c21)
|
||||
select * from cte0;
|
||||
|
||||
## hint对cte定义表进行使用,对比与MySQL的一致
|
||||
explain basic with cte0 AS (select * from t2) select /*+ leading(t2 cte0) use_nl(cte0)*/ * from cte0, t1 where cte0.c21 = t1.c1;
|
||||
|
||||
with cte0 AS (select * from t2) select /*+ leading(t2 cte0) use_nl(cte0)*/ * from cte0, t1 where cte0.c21 = t1.c1;
|
||||
|
||||
## PART 4.1.2 里面是一个set operator
|
||||
explain basic WITH cte AS
|
||||
(
|
||||
SELECT 1 AS col1, 2 AS col2 from dual
|
||||
UNION ALL
|
||||
SELECT 3, 4 from dual
|
||||
)
|
||||
SELECT col1, col2 FROM cte;
|
||||
|
||||
WITH cte AS
|
||||
(
|
||||
SELECT 1 AS col1, 2 AS col2 from dual
|
||||
UNION ALL
|
||||
SELECT 3, 4 from dual
|
||||
)
|
||||
SELECT col1, col2 FROM cte;
|
||||
|
||||
explain basic WITH cte AS
|
||||
(
|
||||
select c1, c2 from t1
|
||||
UNION all
|
||||
select c21, c22 from t2
|
||||
)
|
||||
select c1, c2 from cte;
|
||||
|
||||
WITH cte AS
|
||||
(
|
||||
select c1, c2 from t1
|
||||
UNION all
|
||||
select c21, c22 from t2
|
||||
)
|
||||
select c1, c2 from cte;
|
||||
|
||||
## PART 4.1.3 里面是一个where exist(semi join),顺便测试在cte里面as一个列,在外面使用
|
||||
explain basic WITH cte AS
|
||||
(
|
||||
select 1 as col from t1 where c1 in (select c1 from t1 where exists( (select 1 from dual) union (select 1 from dual)))
|
||||
)
|
||||
select * from cte, t1 where t1.c1 = cte.col;
|
||||
|
||||
WITH cte AS
|
||||
(
|
||||
select 1 as col from t1 where c1 in (select c1 from t1 where exists( (select 1 from dual) union (select 1 from dual)))
|
||||
)
|
||||
select * from cte, t1 where t1.c1 = cte.col;
|
||||
|
||||
## PART 4.2 有针对某一个分区的操作
|
||||
explain basic with cte0 as (select * from t3 partition(p0)) select cte0.c1 from cte0;
|
||||
|
||||
with cte0 as (select * from t3 partition(p0)) select cte0.c1 from cte0;
|
||||
|
||||
explain basic with cte as (select * from t5 partition(p0)) select * from cte;
|
||||
|
||||
with cte as (select * from t5 partition(p0)) select * from cte;
|
||||
|
||||
##############################
|
||||
## section two
|
||||
## PART 1 cte出现在normal型查询语句中
|
||||
##############################
|
||||
## PART 1.1 最基本用法(单表)
|
||||
## 不定义别名列列表的时候最简单的使用方法
|
||||
explain basic WITH
|
||||
cte1 AS (select * from t1)
|
||||
select c1, c2, c3 from cte1;
|
||||
|
||||
WITH
|
||||
cte1 AS (select * from t1)
|
||||
select c1, c2, c3 from cte1;
|
||||
|
||||
## subquery里面取了别名列,看看主句中能否继续使用
|
||||
explain basic with
|
||||
cte1 AS ( select c1 + 1 as col1 from t1)
|
||||
select col1 from cte1;
|
||||
with
|
||||
cte1 AS ( select c1 + 1 as col1 from t1)
|
||||
select col1 from cte1;
|
||||
|
||||
explain basic with
|
||||
cte1 AS ( select c1 + 1 as col1 from t1)
|
||||
select * from cte1;
|
||||
with
|
||||
cte1 AS ( select c1 + 1 as col1 from t1)
|
||||
select * from cte1;
|
||||
|
||||
explain basic with
|
||||
cte1 AS ( select c1 + 1 as col1 from t1)
|
||||
select col1+3 from cte1;
|
||||
with
|
||||
cte1 AS ( select c1 + 1 as col1 from t1)
|
||||
select col1+3 from cte1;
|
||||
|
||||
## 这种cte的列其实可能没法用了
|
||||
explain basic with
|
||||
cte AS (select 1 from t1)
|
||||
select * from cte;
|
||||
with
|
||||
cte AS (select 1 from t1)
|
||||
select * from cte;
|
||||
|
||||
## 主句含有order
|
||||
explain basic WITH cte2 AS (select c1 from t1)
|
||||
select c1 from cte2 order by c1;
|
||||
WITH cte2 AS (select c1 from t1)
|
||||
select c1 from cte2 order by c1;
|
||||
|
||||
## 对主句中的cte取别名后看看能否继续使用
|
||||
explain basic WITH cte2 AS (select c1 from t1)
|
||||
select z1.c1 from cte2 z1, t2 where z1.c1 in (1,4,7,11) and z1.c1 = t2.c21;
|
||||
WITH cte2 AS (select c1 from t1)
|
||||
select z1.c1 from cte2 z1, t2 where z1.c1 in (1,4,7,11) and z1.c1 = t2.c21;
|
||||
|
||||
## 重命名的列出现在where条件中
|
||||
explain basic WITH
|
||||
cte1 AS (SELECT c1 as abc, c2 FROM t1)
|
||||
select abc from cte1, t2 where abc in (1,4,7) and cte1.abc = t2.c21;
|
||||
WITH
|
||||
cte1 AS (SELECT c1 as abc, c2 FROM t1)
|
||||
select abc from cte1, t2 where abc in (1,4,7) and cte1.abc = t2.c21;
|
||||
|
||||
## 重命名的列出现在order+where中
|
||||
explain basic WITH
|
||||
cte1 (name1, name2) AS (select c1, c2 from t1)
|
||||
select name1 from cte1 where name1 in (1,4,11) order by name2;
|
||||
WITH
|
||||
cte1 (name1, name2) AS (select c1, c2 from t1)
|
||||
select name1 from cte1 where name1 in (1,4,11) order by name2;
|
||||
|
||||
## 在field list中写了inline,里面使用了cte
|
||||
explain basic with cte as (select * from t1) select (select count(*) from cte) from t2;
|
||||
with cte as (select * from t1) select (select count(*) from cte) from t2;
|
||||
|
||||
## 在cte在外面使用的时候先被取了别名再使用
|
||||
explain basic with cte AS (select c1 from t1)
|
||||
select cte.c1 from cte z1, cte where z1.c1 = cte.c1;
|
||||
with cte AS (select c1 from t1)
|
||||
select cte.c1 from cte z1, cte where z1.c1 = cte.c1;
|
||||
|
||||
explain basic with cte AS (select c1 from t1)
|
||||
select /*+no_rewrite()*/ cte.c1 from cte z1, cte where z1.c1 = cte.c1;
|
||||
with cte AS (select c1 from t1)
|
||||
select /*+no_rewrite()*/ cte.c1 from cte z1, cte where z1.c1 = cte.c1;
|
||||
|
||||
## join+having not+order by
|
||||
explain basic with
|
||||
cte1 AS( select * from t1)
|
||||
select * from cte1 left join t2 on cte1.c1=t2.c21 where t2.c21 != cte1.c1 order by cte1.c1;
|
||||
with
|
||||
cte1 AS( select * from t1)
|
||||
select * from cte1 left join t2 on cte1.c1=t2.c21 where t2.c21 != cte1.c1 order by cte1.c1;
|
||||
|
||||
## 对cte使用partition命令
|
||||
explain basic WITH cte2 AS (select * from t3)
|
||||
select * from cte2 partition(p0);
|
||||
WITH cte2 AS (select * from t3)
|
||||
select * from cte2 partition(p0);
|
||||
|
||||
## PART 1.2 最基本用法(多表)
|
||||
explain basic WITH
|
||||
cte1 AS (SELECT c1, c2 FROM t1),
|
||||
cte2 AS (SELECT c21, c22 FROM t2)
|
||||
select c21 from cte2;
|
||||
WITH
|
||||
cte1 AS (SELECT c1, c2 FROM t1),
|
||||
cte2 AS (SELECT c21, c22 FROM t2)
|
||||
select c21 from cte2;
|
||||
|
||||
explain basic WITH
|
||||
cte1 (c1)AS(select c1 from t1),
|
||||
cte2 AS (select * from t1)
|
||||
select c1, c2, c3 from cte2;
|
||||
WITH
|
||||
cte1 (c1)AS(select c1 from t1),
|
||||
cte2 AS (select * from t1)
|
||||
select c1, c2, c3 from cte2;
|
||||
|
||||
explain basic WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT c21, c22 FROM t2)
|
||||
SELECT b, d FROM cte1 JOIN cte2
|
||||
on cte1.a = cte2.c;
|
||||
WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT c21, c22 FROM t2)
|
||||
SELECT b, d FROM cte1 JOIN cte2
|
||||
on cte1.a = cte2.c;
|
||||
|
||||
## join+order
|
||||
explain basic WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT c21, c22 FROM t2)
|
||||
select * from cte1 left join cte2 on cte1.a=cte2.c order by cte1.a;
|
||||
WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT c21, c22 FROM t2)
|
||||
select * from cte1 left join cte2 on cte1.a=cte2.c order by cte1.a;
|
||||
|
||||
## 子查询+join
|
||||
explain basic WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT c21, c22 FROM t2)
|
||||
select t11.c11 as c111 from (select c1 as c11, c2 from t1) t11 join cte2 on t11.c2=cte2.c;
|
||||
WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT c21, c22 FROM t2)
|
||||
select t11.c11 as c111 from (select c1 as c11, c2 from t1) t11 join cte2 on t11.c2=cte2.c;
|
||||
|
||||
## 第二个cte的定义引用了第一个cte,主句中两个表做join
|
||||
explain basic WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT a, b FROM cte1)
|
||||
SELECT b, d FROM cte1 JOIN cte2
|
||||
on cte1.a = cte2.c;
|
||||
WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT c21, c22 FROM t2)
|
||||
SELECT b, d FROM cte1 JOIN cte2
|
||||
on cte1.a = cte2.c;
|
||||
|
||||
## 第三cte引用第二个,第二个又引用第一个。结果与oracle一致。
|
||||
explain basic WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT a+1, b-1 FROM cte1),
|
||||
cte3 (e, f) AS (SELECT c*2, d*3 FROM cte2)
|
||||
SELECT a, b, e, f FROM cte1 JOIN cte3
|
||||
on cte1.a < cte3.e;
|
||||
WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT a+1, b-1 FROM cte1),
|
||||
cte3 (e, f) AS (SELECT c*2, d*3 FROM cte2)
|
||||
SELECT a, b, e, f FROM cte1 JOIN cte3
|
||||
on cte1.a < cte3.e;
|
||||
|
||||
## 一个cte是对某个特定分区,一个加了hint,主查询做join
|
||||
with
|
||||
cte0 AS (
|
||||
select * from t3 partition(p0)
|
||||
),
|
||||
cte1 AS (
|
||||
select /*+ index(t4 i1) */ * from t4 where c2 > 0
|
||||
)
|
||||
select cte0.c1, cte1.c1 from cte0, cte1 where cte0.c1 = cte1.c1;
|
||||
|
||||
## cte出现在主查询in子句中,还有exists子句中
|
||||
explain basic WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT c21, c22 FROM t2)
|
||||
select 1 from cte1 where a in (select d from cte2 where exists( (select b from cte1) union (select a from cte1)));
|
||||
WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT c21, c22 FROM t2)
|
||||
select 1 from cte1 where a in (select d from cte2 where exists( (select b from cte1) union (select a from cte1)));
|
||||
|
||||
## 在上面的基础上加入no rewrite hint
|
||||
explain basic WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT c21, c22 FROM t2)
|
||||
select /*+no_rewrite()*/ 1 from cte1 where a in (select d from cte2 where exists( (select b from cte1) union (select a from cte1)));
|
||||
WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT c21, c22 FROM t2)
|
||||
select /*+no_rewrite()*/ 1 from cte1 where a in (select d from cte2 where exists( (select b from cte1) union (select a from cte1)));
|
||||
|
||||
## 主查询是left join+having not+order
|
||||
explain basic WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT c21, c22 FROM t2)
|
||||
select * from cte1 left join cte2 on cte1.a=cte2.c where cte1.b != cte2.d order by cte1.a;
|
||||
WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT c21, c22 FROM t2)
|
||||
select * from cte1 left join cte2 on cte1.a=cte2.c where cte1.b != cte2.d order by cte1.a;
|
||||
|
||||
##############################
|
||||
## PART 2 cte出现在set型查询语句中
|
||||
##############################
|
||||
|
||||
explain basic WITH cte2 AS (select c1 from t1)
|
||||
select c1 from cte2
|
||||
UNION all
|
||||
select c21 from t2;
|
||||
WITH cte2 AS (select c1 from t1)
|
||||
select c1 from cte2
|
||||
UNION all
|
||||
select c21 from t2;
|
||||
|
||||
explain basic WITH cte2 AS (select c1 from t1)
|
||||
select /*+no_rewrite()*/ c1 from cte2
|
||||
UNION all
|
||||
select c21 from t2;
|
||||
WITH cte2 AS (select c1 from t1)
|
||||
select /*+no_rewrite()*/ c1 from cte2
|
||||
UNION all
|
||||
select c21 from t2;
|
||||
|
||||
explain basic WITH cte2 AS (select c1 from t1)
|
||||
select * from t1 intersect (select * from t2);
|
||||
WITH cte2 AS (select c1 from t1)
|
||||
select * from t1 intersect (select * from t2);
|
||||
|
||||
##############################
|
||||
## PART 3 主查询中含有inline cte
|
||||
##############################
|
||||
|
||||
## PART 3.1 inline cte与外层同名/不同名
|
||||
with cte(a) as (select 1 from dual) select * from (with cteb(a) as (select 1 from dual) select * from cteb) abc;
|
||||
|
||||
## 同名,这里应该是查询t1
|
||||
explain basic with cte as (select c21 from t2)
|
||||
select * from (with cte as (select c1 from t1) select * from cte) t;
|
||||
with cte as (select c21 from t2)
|
||||
select * from (with cte as (select c1 from t1) select * from cte) t;
|
||||
|
||||
## 不同名,这里应该是查询t2
|
||||
explain basic with cte as (select c21 from t2)
|
||||
select * from (with cte1 as (select c1 from t1) select * from cte) t;
|
||||
with cte as (select c21 from t2)
|
||||
select * from (with cte1 as (select c1 from t1) select * from cte) t;
|
||||
|
||||
## 三层,这里应该是查询t3
|
||||
explain basic with cte as (select c21 from t2)
|
||||
select * from (with cte as (select c1 from t1) select * from (with cte as (select c1 from t3) select * from cte) cte) t;
|
||||
with cte as (select c21 from t2)
|
||||
select * from (with cte as (select c1 from t1) select * from (with cte as (select c1 from t3) select * from cte) cte) t;
|
||||
|
||||
## PART 3.2 inline cte引用外层cte
|
||||
explain basic with cte as (select 1 from dual) select * from (with cte1 as (select * from cte) select * from cte1);
|
||||
with cte as (select 1 from dual) select * from (with cte1 as (select * from cte) select * from cte1);
|
||||
|
||||
explain basic WITH cte_outer AS (select * from t2)
|
||||
select t1.*, t4.* from t1
|
||||
left join
|
||||
( select c21,c22 from cte_outer) t4
|
||||
on
|
||||
t4.c21=t1.c1;
|
||||
WITH cte_outer AS (select * from t2)
|
||||
select t1.*, t4.* from t1
|
||||
left join
|
||||
( select c21,c22 from cte_outer) t4
|
||||
on
|
||||
t4.c21=t1.c1;
|
||||
|
||||
explain basic WITH cte_outer AS (select * from t2)
|
||||
select t3.*, t4.* from
|
||||
( WITH cte_inner AS (select c1 from t1) select c1 from cte_inner where cte_inner.c1 > 1000) t3
|
||||
left join
|
||||
( WITH cte_inner(a, b) AS (select c1,c2 from t1) select c21,c22 from cte_outer where cte_outer.c21 > 1000) t4
|
||||
on t4.c21=t3.c1
|
||||
order by t4.c22;
|
||||
WITH cte_outer AS (select * from t2)
|
||||
select t3.*, t4.* from
|
||||
( WITH cte_inner AS (select c1 from t1) select c1 from cte_inner where cte_inner.c1 > 1000) t3
|
||||
left join
|
||||
( WITH cte_inner(a, b) AS (select c1,c2 from t1) select c21,c22 from cte_outer where cte_outer.c21 > 1000) t4
|
||||
on t4.c21=t3.c1
|
||||
order by t4.c22;
|
||||
|
||||
## PART 3.3 inline cte中定义表名与已有表名重名,这里应该是查询了t1才对
|
||||
explain basic select * from (WITH t2 AS (select c1 from t1) select c1 from t2 where t2.c1 > 1000) t;
|
||||
select * from (WITH t2 AS (select c1 from t1) select c1 from t2 where t2.c1 > 1000) t;
|
||||
|
||||
## PART 3.4 inline cte出现在field list
|
||||
explain basic select ( WITH cte AS (select c1 from t1) select c1 from cte where cte.c1 > 1000), t2.* from t2;
|
||||
select ( WITH cte AS (select c1 from t1) select c1 from cte where cte.c1 > 1000), t2.* from t2;
|
||||
|
||||
## PART 3.5 inline cte之后看看列能否正常使用
|
||||
explain basic select t3.* from ( WITH cte AS (select c1 from t1) select c1 from cte where cte.c1 > 1000) t3 where t3.c1 > 0;
|
||||
select t3.* from ( WITH cte AS (select c1 from t1) select c1 from cte where cte.c1 > 1000) t3 where t3.c1 > 0;
|
||||
|
||||
explain basic select t3.*, t4.* from
|
||||
(WITH cte AS (select c1 from t1) select c1 from cte where cte.c1 > 1000) t3
|
||||
left join
|
||||
(WITH cte(a, b) AS (select c1,c2 from t1) select a,b from cte where cte.a > 1000) t4
|
||||
on t4.a=t3.c1
|
||||
order by t4.b;
|
||||
select t3.*, t4.* from
|
||||
(WITH cte AS (select c1 from t1) select c1 from cte where cte.c1 > 1000) t3
|
||||
left join
|
||||
(WITH cte(a, b) AS (select c1,c2 from t1) select a,b from cte where cte.a > 1000) t4
|
||||
on t4.a=t3.c1
|
||||
order by t4.b;
|
||||
|
||||
## PART 3.6 inline cte别名后与外部cte做join
|
||||
explain basic with cte as (select * from t1) select * from (with cte as (select * from t2) select * from cte) t3, cte where t3.c21 = cte.c1;
|
||||
with cte as (select * from t1) select * from (with cte as (select * from t2) select * from cte) t3, cte where t3.c21 = cte.c1;
|
||||
|
||||
|
||||
select * from (with cte as (select * from t2) select * from cte) t3, cte where t3.c21 = cte.c1;
|
||||
|
||||
#result is correct, last cte is point to t2
|
||||
with cte as (select * from t1) select (with cte(col1, col2, col3) as(select * from t2) select count(*) from cte) from t1;
|
||||
|
||||
WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT c21, c22 FROM t2)
|
||||
select t11.c11 as c111 from (with cte3 as(select * from t3) select c1 as c11, c2 from cte1) cte1 join cte2 on t11.c2=cte2.c;
|
||||
|
||||
#result is correct
|
||||
WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT c21, c22 FROM t2)
|
||||
select * from (with cte3 as(select * from t3) select c1 as c11, c2 from cte3) cte1 join cte2 on cte1.c11=cte2.c;
|
||||
|
||||
#result is correct
|
||||
WITH
|
||||
cte1 (a, b) AS (SELECT c1, c2 FROM t1),
|
||||
cte2 (c, d) AS (SELECT c21, c22 FROM t2)
|
||||
select * from (with cte2 as(select * from t3) select c1 as c11, c2 from cte2) cte1 join cte2 on cte1.c11=cte2.c;
|
||||
|
||||
##############################
|
||||
## PART 4 歧义语法
|
||||
##############################
|
||||
## 歧义语法
|
||||
## with里面的column和select里面的column重名的情况测试
|
||||
## mysql5.6中alias name不能出现在where子句中,但是可以出现在group by、having、order by子句中
|
||||
## 如果普通列和alias name重复,那么在group by、having子句中优先使用基础列,并汇报WARNNING
|
||||
## order by子句中,优先使用alias name
|
||||
## 这里需要参考mysql8.0中实际使用结果,考虑with clause中定义表中列与基础列重名时的表现
|
||||
|
||||
## PART 4.1 cte使用时一列被别名为另外一个同名列并在where clause中使用
|
||||
with
|
||||
cte1 (c22, c21) AS (select c1, c2 from t1)
|
||||
select c22 as c21, c21 from cte1 where c21 = 12;
|
||||
|
||||
## cte使用时一列被别名为另外一个同名列并在order_by_clause中使用
|
||||
##ERROR 1052 (23000): Column 'c21' in order clause is ambiguous
|
||||
with
|
||||
cte1 (c22, c21) AS (select c1, c2 from t1)
|
||||
select c22 as c21, c21 from cte1 order by c21;
|
||||
|
||||
## cte使用时一列被别名为另外一个同名列并在having clause中使用
|
||||
#ERROR 1052 (23000): Column 'c21' in having clause is ambiguous
|
||||
with
|
||||
cte1 (c22, c21) AS (select c1, c2 from t1)
|
||||
select c22 as c21, c21 from cte1 having c21 > 0;
|
||||
|
||||
## cte使用时一列被别名为另外一个同名列并在group_by_clause中使用
|
||||
#ERROR 1052 (23000): Column 'c21' in group statement is ambiguous
|
||||
with
|
||||
cte1 (c22, c21) AS (select c1, c2 from t1)
|
||||
select c22 as c21, c21 from cte1 group by c21;
|
||||
|
||||
with
|
||||
cte1 (c22, c21) AS (select * from t1)
|
||||
select c22 as c21, c21 from cte1 group by c21;
|
||||
|
||||
## cte的列名已经无法在被使用了,这种用法比较特殊
|
||||
explain basic with cte as (select count(*) as k from t1) select * from cte where k = 1;
|
||||
with cte as (select count(*) as k from t1) select * from cte where k = 1;
|
||||
|
||||
##############################
|
||||
## section three
|
||||
## PART 1 select for update
|
||||
##############################
|
||||
|
||||
explain basic WITH
|
||||
cte0 AS ( select * from t1)
|
||||
select * from cte0 for update;
|
||||
WITH
|
||||
cte0 AS ( select * from t1)
|
||||
select * from cte0 for update;
|
||||
|
||||
##############################
|
||||
## PART 2 insert into
|
||||
##############################
|
||||
|
||||
explain basic insert into t1 with cte as (select * from t1) SELECT * FROM cte;
|
||||
insert into t1 with cte as (select * from t1) SELECT * FROM cte;
|
||||
|
||||
explain basic insert into t1 with cte (a,b,c) as (select c21,c22,c23 from t2) select a,b,a from cte;
|
||||
insert into t1 with cte (a,b,c) as (select c21,c22,c23 from t2) select a,b,a from cte;
|
||||
select * from t1;
|
||||
|
||||
##############################
|
||||
## PART 3 update select
|
||||
##############################
|
||||
|
||||
explain basic update t1 set c1=(with cte as (select count(*)+99 from t2 where c21=1) select * from cte) where c2 = 2;
|
||||
update t1 set c1=(with cte as (select count(*)+99 from t2 where c21=1) select * from cte) where c2 = 2;
|
||||
select * from t1;
|
||||
|
||||
##############################
|
||||
## PART 4 select when
|
||||
##############################
|
||||
|
||||
explain basic with cte as (select c1, max(c2), CASE max(c2) when 4 then 4 when 43 then 43 else 1 end from t1 group by c1 order by c1) select * from cte;
|
||||
with cte as (select c1, max(c2), CASE max(c2) when 4 then 4 when 43 then 43 else 1 end from t1 group by c1 order by c1) select * from cte;
|
||||
|
||||
explain basic with cte(c1, c2) as (select t1.c1, t1.c2 from t1, t2 where t1.c1 = t2.c21) select c1, max(c2), CASE max(c2) when 4 then 4 when 43 then 43 else 1 end from cte group by c1 order by c1;
|
||||
with cte(c1, c2) as (select t1.c1, t1.c2 from t1, t2 where t1.c1 = t2.c21) select c1, max(c2), CASE max(c2) when 4 then 4 when 43 then 43 else 1 end from cte group by c1 order by c1;
|
||||
|
||||
##############################
|
||||
## PART 5 delete from
|
||||
##############################
|
||||
|
||||
explain basic delete from t1 where c1 = ( with cte as (select max( c1 ) from ( select * from t1 )) select * from cte);
|
||||
delete from t1 where c1 = ( with cte as (select max( c1 ) from ( select * from t1 )) select * from cte);
|
||||
|
||||
explain basic delete from t1 where c1 = ( with cte (a) as (select max( c1 ) from t1 ) select * from cte);
|
||||
delete from t1 where c1 = ( with cte (a) as (select max( c1 ) from t1 ) select * from cte);
|
||||
|
||||
##############################
|
||||
## other
|
||||
##############################
|
||||
with cte as (select * from t1) select 1 from dual;
|
||||
|
||||
|
||||
|
||||
|
@ -0,0 +1,55 @@
|
||||
with cte(a,b) as (select 1 from dual) select * from cte;
|
||||
|
||||
with cte(a,b) as (with cte2(a,b) as (select 1,1 from dual) select a,b from cte) select * from cte;
|
||||
|
||||
with cte(a,a) as (select 1 from dual) select * from cte;
|
||||
|
||||
with cte as (select 1,1 from dual union all select a+1,b+1 from cte where cte.a < 10) select * from cte;
|
||||
|
||||
# MySQL不支持search depth关键字
|
||||
with cte(a,b,c) as
|
||||
(
|
||||
select 1,2,3 from dual
|
||||
union all
|
||||
select a+1,b+1,c+1 from cte where cte.c < 10
|
||||
) search depth first by d set pcol select * from cte;
|
||||
|
||||
# MySQL不支持cycle关键字
|
||||
with cte(n, x) as (select /*+ materialize */ 1,2 from dual) cycle n,n set iscyc to 'aaaaay' default 'n' select * from cte;
|
||||
|
||||
with cte(a,b,c) as
|
||||
(
|
||||
select 1,2,3 from dual
|
||||
union
|
||||
select a+1,b+1,c+1 from cte, cte b where cte.c < 10 and b.c = cte.c
|
||||
) select * from cte;
|
||||
|
||||
with cte(a,b,c) as
|
||||
(
|
||||
select 1,2,3 from dual
|
||||
union all
|
||||
select 1,2,3 from dual
|
||||
union all
|
||||
select a+1,b+1,c+1 from cte, cte b where cte.c < 10 and b.c = cte.c
|
||||
) select * from cte;
|
||||
|
||||
with t1 as (select c1 from t1) select * from t1;
|
||||
|
||||
## success
|
||||
with cte1(a,b) as (select 'a','b' from dual), cte2 as (select * from cte1 where b > 'c'), cte3 as (select * from cte2 where a > 1 union select * from cte2 where a > 1) select * from cte3;
|
||||
|
||||
with cte(a) as (select 1,1 from dual union all select a+1, a+1 from cte where a+1 < 10) select * from cte;
|
||||
|
||||
with cte(n) AS (select 1 from dual UNION ALL select n+1 from cte where n < 3 UNION ALL select 2 from dual) select * from cte;
|
||||
|
||||
with cte(n) AS ( select 1 from dual UNION ALL select sum(n+1) from cte) select * from cte;
|
||||
|
||||
with cte(n) AS ( select 1 from dual UNION ALL select (select 1 from dual) from cte where cte.n < 2) select * from cte;
|
||||
|
||||
with cte (c1, c2, c3) as ( select * from ( select c1, c2, c3 from t1 union select c1, c2, c3 from t1) where c1 = 1 union all select * from t1 join cte c on t1.c1 = c.c1 where c.c1 < 10 ) select * from cte;
|
||||
|
||||
with cte(n) AS ( select 1 from cte) select * from cte;
|
||||
|
||||
with cte(n) AS (select 1 from dual UNION ALL select n+1 from cte where n < 3 order by n ) select * from cte;
|
||||
|
||||
|
433
test/mysql_test/test_suite/with_clause/t/cte_mysql_official.test
Normal file
433
test/mysql_test/test_suite/with_clause/t/cte_mysql_official.test
Normal file
@ -0,0 +1,433 @@
|
||||
# cases in MySQL document: https://dev.mysql.com/doc/refman/8.0/en/with.html
|
||||
|
||||
WITH RECURSIVE cte (n) AS
|
||||
(
|
||||
SELECT 1
|
||||
UNION ALL
|
||||
SELECT n + 1 FROM cte WHERE n < 5
|
||||
)
|
||||
SELECT * FROM cte;
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT 1 AS n, CAST('abc' AS CHAR(20)) AS str
|
||||
UNION ALL
|
||||
SELECT n + 1, CONCAT(str, str) FROM cte WHERE n < 3
|
||||
)
|
||||
SELECT * FROM cte;
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT 1 AS n, 1 AS p, -1 AS q
|
||||
UNION ALL
|
||||
SELECT n + 1, q * 2, p * 2 FROM cte WHERE n < 5
|
||||
)
|
||||
SELECT * FROM cte;
|
||||
|
||||
WITH RECURSIVE fibonacci (n, fib_n, next_fib_n) AS
|
||||
(
|
||||
SELECT 1, 0, 1
|
||||
UNION ALL
|
||||
SELECT n + 1, next_fib_n, fib_n + next_fib_n
|
||||
FROM fibonacci WHERE n < 10
|
||||
)
|
||||
SELECT * FROM fibonacci;
|
||||
|
||||
WITH RECURSIVE fibonacci (n, fib_n, next_fib_n) AS
|
||||
(
|
||||
SELECT 1, 0, 1
|
||||
UNION ALL
|
||||
SELECT n + 1, next_fib_n, fib_n + next_fib_n
|
||||
FROM fibonacci WHERE n < 10
|
||||
)
|
||||
SELECT fib_n FROM fibonacci WHERE n = 8;
|
||||
|
||||
create table sales(date DATE,price NUMBER(7,2));
|
||||
insert into sales values(str_to_date('2017-01-03', '%Y-%m-%d'),100);
|
||||
insert into sales values(str_to_date('2017-01-03', '%Y-%m-%d'),200);
|
||||
insert into sales values(str_to_date('2017-01-06', '%Y-%m-%d'),50);
|
||||
insert into sales values(str_to_date('2017-01-08', '%Y-%m-%d'),10);
|
||||
insert into sales values(str_to_date('2017-01-08', '%Y-%m-%d'),20);
|
||||
insert into sales values(str_to_date('2017-01-08', '%Y-%m-%d'),150);
|
||||
insert into sales values(str_to_date('2017-01-10', '%Y-%m-%d'),5);
|
||||
|
||||
SELECT * FROM sales ORDER BY date, price;
|
||||
|
||||
SELECT date, SUM(price) AS sum_price
|
||||
FROM sales
|
||||
GROUP BY date
|
||||
ORDER BY date;
|
||||
|
||||
WITH RECURSIVE dates (date) AS
|
||||
(
|
||||
SELECT MIN(date) FROM sales
|
||||
UNION ALL
|
||||
SELECT date + INTERVAL 1 DAY FROM dates
|
||||
WHERE date + INTERVAL 1 DAY <= (SELECT MAX(date) FROM sales)
|
||||
)
|
||||
SELECT * FROM dates;
|
||||
|
||||
WITH RECURSIVE dates (date) AS
|
||||
(
|
||||
SELECT MIN(date) FROM sales
|
||||
UNION ALL
|
||||
SELECT date + INTERVAL 1 DAY FROM dates
|
||||
WHERE date + INTERVAL 1 DAY <= (SELECT MAX(date) FROM sales)
|
||||
)
|
||||
SELECT dates.date, COALESCE(SUM(price), 0) AS sum_price
|
||||
FROM dates LEFT JOIN sales ON dates.date = sales.date
|
||||
GROUP BY dates.date
|
||||
ORDER BY dates.date;
|
||||
|
||||
################################################################################################
|
||||
### PART 1 SQL syntax
|
||||
################################################################################################
|
||||
|
||||
WITH cte1(txt) AS (SELECT "This "),
|
||||
cte2(txt) AS (SELECT CONCAT(cte1.txt,"is a ") FROM cte1),
|
||||
cte3(txt) AS (SELECT "nice query" UNION
|
||||
SELECT "query that rocks" UNION
|
||||
SELECT "query"),
|
||||
cte4(txt) AS (SELECT concat(cte2.txt, cte3.txt) FROM cte2, cte3)
|
||||
SELECT MAX(txt), MIN(txt) FROM cte4;
|
||||
|
||||
WITH RECURSIVE my_cte AS
|
||||
(
|
||||
SELECT 1 AS n
|
||||
UNION ALL
|
||||
SELECT 1+n FROM my_cte WHERE n<10
|
||||
)
|
||||
SELECT * FROM my_cte;
|
||||
|
||||
CREATE TABLE numbers
|
||||
WITH RECURSIVE my_cte(n) AS
|
||||
(
|
||||
SELECT 1
|
||||
UNION ALL
|
||||
SELECT 1+n FROM my_cte WHERE n<6
|
||||
)
|
||||
SELECT * FROM my_cte;
|
||||
SELECT * FROM numbers;
|
||||
|
||||
INSERT INTO numbers
|
||||
WITH RECURSIVE my_cte(n) AS
|
||||
(
|
||||
SELECT 1
|
||||
UNION ALL
|
||||
SELECT 1+n FROM my_cte WHERE n<6
|
||||
)
|
||||
SELECT * FROM my_cte;
|
||||
|
||||
SELECT * FROM numbers;
|
||||
|
||||
DELETE FROM numbers
|
||||
WHERE numbers.n >
|
||||
(
|
||||
WITH RECURSIVE my_cte(n) AS
|
||||
(
|
||||
SELECT 1
|
||||
UNION ALL
|
||||
SELECT 1+n FROM my_cte WHERE n<6
|
||||
)
|
||||
SELECT AVG(n)/2 FROM my_cte
|
||||
);
|
||||
SELECT * FROM numbers;
|
||||
|
||||
################################################################################################
|
||||
### PART 2 generating series
|
||||
################################################################################################
|
||||
WITH RECURSIVE my_cte AS
|
||||
(
|
||||
SELECT 1 as f, 1 as next_f
|
||||
UNION ALL
|
||||
SELECT next_f, f+next_f FROM my_cte WHERE f < 500
|
||||
)
|
||||
SELECT * FROM my_cte;
|
||||
|
||||
WITH RECURSIVE
|
||||
digits AS
|
||||
(
|
||||
SELECT '0' AS d UNION ALL SELECT '1'
|
||||
),
|
||||
strings AS
|
||||
(
|
||||
SELECT CAST('' AS CHAR(4)) AS s
|
||||
UNION ALL
|
||||
SELECT CONCAT(strings.s, digits.d)
|
||||
FROM strings, digits
|
||||
WHERE LENGTH(strings.s) < 4
|
||||
)
|
||||
SELECT * FROM strings WHERE LENGTH(s)=4;
|
||||
|
||||
################################################################################################
|
||||
### PART 3 hierarchies
|
||||
################################################################################################
|
||||
CREATE TABLE category(
|
||||
category_id INT AUTO_INCREMENT PRIMARY KEY,
|
||||
name VARCHAR(20) NOT NULL,
|
||||
parent INT DEFAULT NULL
|
||||
);
|
||||
|
||||
INSERT INTO category VALUES(1,'ELECTRONICS',NULL),(2,'TELEVISIONS',1),(3,'TUBE',2),
|
||||
(4,'LCD',2),(5,'PLASMA',2),(6,'PORTABLE ELECTRONICS',1),(7,'MP3 PLAYERS',6),(8,'FLASH',7),
|
||||
(9,'CD PLAYERS',6),(10,'2 WAY RADIOS',6);
|
||||
|
||||
SELECT * FROM category ORDER BY category_id;
|
||||
|
||||
#Retrieving a Full Tree
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
# seed SELECT
|
||||
SELECT category_id, name FROM category WHERE parent IS NULL
|
||||
UNION ALL
|
||||
# recursive SELECT
|
||||
SELECT c.category_id, c.name FROM category c JOIN cte
|
||||
ON cte.category_id=c.parent # find children
|
||||
)
|
||||
SELECT category_id, name FROM cte;
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT category_id, name, 0 AS depth FROM category WHERE parent IS NULL
|
||||
UNION ALL
|
||||
SELECT c.category_id, c.name, cte.depth+1 FROM category c JOIN cte ON
|
||||
cte.category_id=c.parent
|
||||
)
|
||||
SELECT * FROM cte ORDER BY depth;
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT category_id, name, CAST(category_id AS CHAR(200)) AS path
|
||||
FROM category WHERE parent IS NULL
|
||||
UNION ALL
|
||||
SELECT c.category_id, c.name, CONCAT(cte.path, ",", c.category_id)
|
||||
FROM category c JOIN cte ON cte.category_id=c.parent
|
||||
)
|
||||
SELECT * FROM cte ORDER BY path;
|
||||
|
||||
#Finding all the leaf nodes
|
||||
|
||||
SELECT category_id, name FROM category
|
||||
WHERE category_id NOT IN
|
||||
# IDs of all parents:
|
||||
(SELECT parent FROM category WHERE parent IS NOT NULL);
|
||||
|
||||
#Retrieving a Single Path
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT name, parent FROM category WHERE name='FLASH'
|
||||
UNION ALL
|
||||
SELECT c.name, c.parent FROM category c JOIN cte
|
||||
ON c.category_id=cte.parent # find parent
|
||||
)
|
||||
SELECT * FROM cte;
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT name, parent, 0 as depth FROM category WHERE name='FLASH'
|
||||
UNION ALL
|
||||
SELECT c.name, c.parent, cte.depth-1 FROM category c JOIN cte
|
||||
ON c.category_id=cte.parent
|
||||
)
|
||||
SELECT * FROM cte ORDER BY depth;
|
||||
|
||||
#Finding the Depth of the Nodes
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT category_id, CAST(name AS CHAR(200)) AS name,
|
||||
CAST(category_id AS CHAR(200)) AS path,
|
||||
0 as depth
|
||||
FROM category WHERE parent IS NULL
|
||||
UNION ALL
|
||||
SELECT c.category_id,
|
||||
CONCAT(REPEAT(' ', cte.depth+1), c.name), # indentation
|
||||
CONCAT(cte.path, ",", c.category_id),
|
||||
cte.depth+1
|
||||
FROM category c JOIN cte ON
|
||||
cte.category_id=c.parent
|
||||
)
|
||||
SELECT * FROM cte ORDER BY path;
|
||||
|
||||
#Depth of a sub-tree
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT category_id, name,
|
||||
CAST(category_id AS CHAR(200)) AS path,
|
||||
0 as depth
|
||||
FROM category WHERE name='PORTABLE ELECTRONICS' # sub-tree root
|
||||
UNION ALL
|
||||
SELECT c.category_id,
|
||||
c.name,
|
||||
CONCAT(cte.path, ",", c.category_id),
|
||||
cte.depth+1
|
||||
FROM category c JOIN cte
|
||||
ON cte.category_id=c.parent
|
||||
)
|
||||
SELECT * FROM cte ORDER BY path;
|
||||
|
||||
#Find the immediate subordinates of a node
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT category_id, name, 0 as depth
|
||||
FROM category WHERE name='PORTABLE ELECTRONICS'
|
||||
UNION ALL
|
||||
SELECT c.category_id, c.name, cte.depth+1
|
||||
FROM category c JOIN cte
|
||||
ON cte.category_id=c.parent
|
||||
WHERE cte.depth=0
|
||||
)
|
||||
SELECT * FROM cte;
|
||||
|
||||
#Aggregate functions in a nested set
|
||||
|
||||
CREATE TABLE product(
|
||||
category_id INT AUTO_INCREMENT PRIMARY KEY,
|
||||
name VARCHAR(20) NOT NULL,
|
||||
parent INT DEFAULT NULL
|
||||
);
|
||||
|
||||
INSERT INTO product VALUES(1,'ELECTRONICS',NULL),(2,'TELEVISIONS',1),(3,'TUBE',2),
|
||||
(4,'LCD',2),(5,'PLASMA',2),(6,'PORTABLE ELECTRONICS',1),(7,'MP3 PLAYERS',6),(8,'FLASH',7),
|
||||
(9,'CD PLAYERS',6),(10,'2 WAY RADIOS',6);
|
||||
|
||||
|
||||
WITH RECURSIVE cte AS
|
||||
(
|
||||
SELECT c.category_id, c.name AS cat_name, c.parent, p.name AS prod_name
|
||||
FROM category c JOIN product p ON c.category_id=p.category_id
|
||||
UNION ALL
|
||||
SELECT c.category_id, c.name, c.parent, cte.prod_name
|
||||
FROM cte JOIN category c ON c.category_id=cte.parent
|
||||
)
|
||||
SELECT cat_name, COUNT(*) AS prod_in_cat FROM cte
|
||||
GROUP BY cat_name;
|
||||
|
||||
|
||||
################################################################################################
|
||||
### PART 4 depth-first or breadth-first traversal, transitive closure, cycle avoidance
|
||||
################################################################################################
|
||||
|
||||
#Depth-first or breadth-first
|
||||
|
||||
CREATE TABLE tree (person CHAR(20), parent CHAR(20));
|
||||
INSERT INTO tree VALUES
|
||||
('Robert I', NULL),
|
||||
('Thurimbert', 'Robert I'),
|
||||
('Robert II', 'Thurimbert'),
|
||||
('Cancor', 'Thurimbert'),
|
||||
('Landrade', 'Thurimbert'),
|
||||
('Ingramm', 'Thurimbert'),
|
||||
('Robert III', 'Robert II'),
|
||||
('Chaudegrand', 'Landrade'),
|
||||
('Ermengarde', 'Ingramm');
|
||||
|
||||
WITH RECURSIVE descendants AS
|
||||
(
|
||||
SELECT person
|
||||
FROM tree
|
||||
WHERE person='Thurimbert'
|
||||
UNION ALL
|
||||
SELECT t.person
|
||||
FROM descendants d, tree t
|
||||
WHERE t.parent=d.person
|
||||
)
|
||||
SELECT * FROM descendants;
|
||||
|
||||
WITH RECURSIVE descendants AS
|
||||
(
|
||||
SELECT person, 1 as level
|
||||
FROM tree
|
||||
WHERE person='Thurimbert'
|
||||
UNION ALL
|
||||
SELECT t.person, d.level+1
|
||||
FROM descendants d, tree t
|
||||
WHERE t.parent=d.person
|
||||
)
|
||||
SELECT * FROM descendants ORDER BY level;
|
||||
|
||||
WITH RECURSIVE descendants AS
|
||||
(
|
||||
SELECT person, CAST(person AS CHAR(500)) AS path
|
||||
FROM tree
|
||||
WHERE person='Thurimbert'
|
||||
UNION ALL
|
||||
SELECT t.person, CONCAT(d.path, ',', t.person)
|
||||
FROM descendants d, tree t
|
||||
WHERE t.parent=d.person
|
||||
)
|
||||
SELECT * FROM descendants ORDER BY path;
|
||||
|
||||
#Computing transitive closures with simple cycle avoidance
|
||||
|
||||
CREATE TABLE rockets
|
||||
(origin CHAR(20), destination CHAR(20), trip_time INT);
|
||||
INSERT INTO rockets VALUES
|
||||
('Earth', 'Mars', 2),
|
||||
('Mars', 'Jupiter', 3),
|
||||
('Jupiter', 'Saturn', 4);
|
||||
|
||||
WITH RECURSIVE all_destinations AS
|
||||
(
|
||||
SELECT destination AS planet
|
||||
FROM rockets
|
||||
WHERE origin='Earth'
|
||||
UNION ALL
|
||||
SELECT r.destination
|
||||
FROM rockets r, all_destinations d
|
||||
WHERE r.origin=d.planet
|
||||
)
|
||||
SELECT * FROM all_destinations;
|
||||
|
||||
INSERT INTO rockets VALUES ('Saturn', 'Earth', 9);
|
||||
|
||||
WITH RECURSIVE all_destinations AS
|
||||
(
|
||||
SELECT destination AS planet
|
||||
FROM rockets
|
||||
WHERE origin='Earth'
|
||||
UNION ALL
|
||||
SELECT r.destination
|
||||
FROM rockets r, all_destinations d
|
||||
WHERE r.origin=d.planet
|
||||
)
|
||||
SELECT * FROM all_destinations;
|
||||
|
||||
#More complex cycle avoidance
|
||||
|
||||
WITH RECURSIVE all_destinations AS
|
||||
(
|
||||
SELECT destination AS planet, trip_time AS total_time,
|
||||
CAST(destination AS CHAR(500)) AS path
|
||||
FROM rockets
|
||||
WHERE origin='Earth'
|
||||
UNION ALL
|
||||
SELECT r.destination, d.total_time+r.trip_time,
|
||||
CONCAT(d.path, ',', r.destination)
|
||||
FROM rockets r, all_destinations d
|
||||
WHERE r.origin=d.planet
|
||||
AND FIND_IN_SET(r.destination, d.path)=0
|
||||
)
|
||||
SELECT * FROM all_destinations;
|
||||
|
||||
|
||||
WITH RECURSIVE all_destinations AS
|
||||
(
|
||||
SELECT destination AS planet, trip_time AS total_time,
|
||||
CAST(destination AS CHAR(500)) AS path, 0 AS is_cycle
|
||||
FROM rockets
|
||||
WHERE origin='Earth'
|
||||
UNION ALL
|
||||
SELECT r.destination, d.total_time+r.trip_time,
|
||||
CONCAT(d.path, ',', r.destination),
|
||||
FIND_IN_SET(r.destination, d.path)!=0
|
||||
FROM rockets r, all_destinations d
|
||||
WHERE r.origin=d.planet
|
||||
AND is_cycle=0
|
||||
)
|
||||
SELECT * FROM all_destinations;
|
||||
|
@ -0,0 +1,571 @@
|
||||
drop table EMP;
|
||||
create table EMP (
|
||||
EMPno number,
|
||||
ENAME VARCHAR(30),
|
||||
JOB VARCHAR(30),
|
||||
MGR number(4),
|
||||
HIREDATE date,
|
||||
SAL number(7,2),
|
||||
COMM number(7,2),
|
||||
DEPTNO number(2)
|
||||
) ;
|
||||
|
||||
INSERT INTO EMP values (7369,'SMITH','CLERK',7902, str_to_date('1980-12-17','%Y-%m-%d'),800,NULL, 20) ;
|
||||
INSERT INTO EMP VALUES (7499, 'ALLEN','SALESMAN',7698,str_to_date('1981-02-20','%Y-%m-%d'),1600,300,30) ;
|
||||
INSERT INTO EMP VALUES (7521,'WARD','SALESMAN',7698, str_to_date('1981-02-22','%Y-%m-%d'),1250, 500, 30) ;
|
||||
INSERT INTO EMP VALUES (7566,'JONES','MANAGER',7839, str_to_date('1981-08-02','%Y-%m-%d'), 2975, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES (7654,'MARTIN','SALESMAN', 7698, str_to_date('1981-09-28','%Y-%m-%d'), 1250, 1400, 30) ;
|
||||
INSERT INTO EMP VALUES (7698, 'BLAKE','MANAGER', 7839, str_to_date('1981-05-01','%Y-%m-%d'), 2850, NULL, 30) ;
|
||||
INSERT INTO EMP VALUES (7782, 'CLARK','MANAGER', 7839, str_to_date('1981-06-09','%Y-%m-%d'), 2450, NULL, 10) ;
|
||||
insert into EMP values (7788,'SCOTT','ANALYST', 7566, str_to_date('1987-08-19','%Y-%m-%d'), 3000, null, 20) ;
|
||||
INSERT INTO EMP VALUES (7839, 'KING','PRESIDENT', NULL, str_to_date('1981-11-17','%Y-%m-%d'), 5000, NULL, 10) ;
|
||||
INSERT INTO EMP VALUES (7844, 'TURNER','SALESMAN', 7698, str_to_date('1981-09-08','%Y-%m-%d'), 1500, 0, 30) ;
|
||||
INSERT INTO EMP VALUES(7876, 'ADAMS','CLERK', 7788, str_to_date('1987-05-23','%Y-%m-%d'), 1100, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES(7900, 'JAMES', 'CLEARK', 7698, str_to_date('1981-12-03','%Y-%m-%d'), 950, NULL, 30) ;
|
||||
INSERT INTO EMP VALUES(7902, 'FORD','ANALYST',7566, str_to_date('1981-12-03','%Y-%m-%d'), 3000, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES(7934,'MILLER','CLERK', 7782, str_to_date('1982-01-23','%Y-%m-%d'), 1300,NULL, 10) ;
|
||||
|
||||
drop table emp1;
|
||||
CREATE TABLE emp1 (
|
||||
empno VARCHAR(4000) NOT NULL,
|
||||
ename VARCHAR(14),
|
||||
job VARCHAR(9),
|
||||
mgr VARCHAR(4000),
|
||||
hiredate DATE,
|
||||
sal NUMBER(7,2),
|
||||
comm NUMBER(7,2),
|
||||
deptno NUMBER(2));
|
||||
|
||||
INSERT INTO emp1 values (7369, 'SMITH', 'CLERK', 7902, str_to_date('1980-12-17',
|
||||
'%Y-%m-%d'), 800, null, 20);
|
||||
INSERT INTO emp1 values (7499, 'ALLEN', 'SALESMAN', 7698, str_to_date('1981-02-20', '%Y-%m-%d'), 1600, 300, 30);
|
||||
INSERT INTO emp1 values (7521, 'WARD', 'SALESMAN', 7698, str_to_date('1981-02-22',
|
||||
'%Y-%m-%d'), 1250, 500, 30);
|
||||
INSERT INTO emp1 values (7566, 'JONES', 'MANAGER', 7839, str_to_date('1981-08-02',
|
||||
'%Y-%m-%d'), 2975, null, 20);
|
||||
INSERT INTO emp1 values (7654, 'MARTIN', 'SALESMAN', 7698, str_to_date('1981-09-28', '%Y-%m-%d'), 1250, 1400, 30);
|
||||
INSERT INTO emp1 values (7698, 'BLAKE', 'MANAGER', 7839, str_to_date('1981-05-01',
|
||||
'%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (7782, 'CLARK', 'MANAGER', 7839, str_to_date('1981-06-09'
|
||||
, '%Y-%m-%d'), 2450, null, 10);
|
||||
INSERT INTO emp1 values (7788, 'SCOTT', 'ANALYST', 7566, str_to_date('1987-08-19',
|
||||
'%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp1 values (7839, 'KING', 'PRESIDENT', null, str_to_date('1981-11-17', '%Y-%m-%d'), 5000, null, 10);
|
||||
INSERT INTO emp1 values (7844, 'TURNER', 'SALESMAN', 7698, str_to_date('1981-09-08', '%Y-%m-%d'), 1500, 0, 30);
|
||||
INSERT INTO emp1 values (7876, 'ADAMS', 'CLERK', 7788, str_to_date('1987-05-23',
|
||||
'%Y-%m-%d'), 1100, null, 20);
|
||||
INSERT INTO emp1 values (7900, 'JAMES', 'CLERK', 7698, str_to_date('1981-12-03',
|
||||
'%Y-%m-%d'), 950, null, 30);
|
||||
INSERT INTO emp1 values (7902, 'FORD', 'ANALYST', 7566, str_to_date('1981-12-03',
|
||||
'%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp1 values (7934, 'MILLER', 'CLERK', 7782, str_to_date('1982-01-23',
|
||||
'%Y-%m-%d'), 1300, null, 10);
|
||||
|
||||
INSERT INTO emp1 values (8100, 'Eve', 'MANAGER', 7839, str_to_date('1984-05-01',
|
||||
'%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (8101, 'Eve1', 'MANAGER', 8100, str_to_date('1984-05-01',
|
||||
'%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (8108, 'Eve8', 'CLERK', 8101, str_to_date('1984-05-01',
|
||||
'%Y-%m-%d'), 2850, null, 30);
|
||||
|
||||
result_format: 4
|
||||
## =======================================================================
|
||||
## Test Case 1:
|
||||
## - recursive WITH Query: Nested Loop Join
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ USE_NL(r e) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 2:
|
||||
## - recursive WITH Query: SORT MERGE Join
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ USE_MERGE(r e) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 3:
|
||||
## - recursive WITH Query: Hash Join
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ USE_HASH(r e) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 4:
|
||||
## - recursive WITH Query: Join in Initialisation Branch
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT /*+ USE_NL(e d) */ e.ename, e.mgr, e.empno
|
||||
FROM emp e, emp d
|
||||
WHERE e.sal = d. sal
|
||||
UNION ALL
|
||||
SELECT /*+ USE_HASH(r e) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e, emp d
|
||||
WHERE r.empno = e.mgr and e.sal = d.sal
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 6:
|
||||
## - recursive WITH Query: Hash Join without using hints
|
||||
## Static input on build side and fits in memory
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno
|
||||
FROM emp e, rw r
|
||||
WHERE e.mgr = r.empno
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 7:
|
||||
## - recursive WITH Query: Hash Join without using hints
|
||||
## Static input on probe side and fits in memory
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## 测试8-15都是在测试join的顺序或者hint的顺序
|
||||
## Test Case 8:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## pump >< emp >< emp1
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (empno, mgr, iters, sal) AS
|
||||
(
|
||||
SELECT e.empno, e.mgr, 1, e.sal
|
||||
FROM emp e, emp1 n1, emp1 n2
|
||||
WHERE e.empno = n1.empno and e.mgr = n2.empno and e.empno < e.mgr
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */r.empno, e.mgr, r.iters + 1, r.sal + e.sal
|
||||
FROM rw r, emp e, emp1 n
|
||||
WHERE r.mgr = e.empno and e.mgr = n.empno and e.empno < e.mgr
|
||||
)
|
||||
SELECT *
|
||||
FROM rw
|
||||
ORDER BY 1, 3;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 9:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## emp >< pump >< emp1
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (empno, mgr, iters, sal) AS
|
||||
(
|
||||
SELECT e.empno, e.mgr, 1, e.sal
|
||||
FROM emp e, emp1 n1, emp1 n2
|
||||
WHERE e.empno = n1.empno and e.mgr = n2.empno and e.empno < e.mgr
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */r.empno, e.mgr, r.iters + 1, r.sal + e.sal
|
||||
FROM emp e, rw r, emp1 n
|
||||
WHERE e.empno = r.mgr and e.mgr = n.empno and e.empno < e.mgr
|
||||
)
|
||||
SELECT *
|
||||
FROM rw
|
||||
ORDER BY 1, 3;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 10:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## emp >< emp1 >< pump
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (empno, mgr, iters, sal) AS
|
||||
(
|
||||
SELECT e.empno, e.mgr, 1, e.sal
|
||||
FROM emp e, emp1 n1, emp1 n2
|
||||
WHERE e.empno = n1.empno and e.mgr = n2.empno and e.empno < e.mgr
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */r.empno, e.mgr, r.iters + 1, r.sal + e.sal
|
||||
FROM emp e, emp1 n, rw r
|
||||
WHERE e.mgr = n.empno and e.empno = r.mgr and e.empno < e.mgr
|
||||
)
|
||||
SELECT *
|
||||
FROM rw
|
||||
ORDER BY 1, 3;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 11:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## emp1 >< emp >< pump
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (empno, mgr, iters, sal) AS
|
||||
(
|
||||
SELECT e.empno, e.mgr, 1, e.sal
|
||||
FROM emp e, emp1 n1, emp1 n2
|
||||
WHERE e.empno = n1.empno and e.mgr = n2.empno and e.empno < e.mgr
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */r.empno, e.mgr, r.iters + 1, r.sal + e.sal
|
||||
FROM emp1 n, emp e, rw r
|
||||
WHERE n.empno = e.mgr and e.empno = r.mgr and e.empno < e.mgr
|
||||
)
|
||||
SELECT *
|
||||
FROM rw
|
||||
ORDER BY 1, 3;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 12:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## pump >< emp
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 13:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## emp >< pump
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */ e.ename, e.mgr, e.empno
|
||||
FROM emp e, rw r
|
||||
WHERE e.mgr = r.empno
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 14:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## emp1 >< pump >< emp
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (empno, mgr, iters, sal) AS
|
||||
(
|
||||
SELECT e.empno, e.mgr, 1, e.sal
|
||||
FROM emp e, emp1 n1, emp1 n2
|
||||
WHERE e.empno = n1.empno and e.mgr = n2.empno and e.empno < e.mgr
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */r.empno, e.mgr, r.iters + 1, r.sal + e.sal
|
||||
FROM emp1 n, rw r, emp e
|
||||
WHERE n.empno = e.mgr and r.mgr = e.empno and e.empno < e.mgr
|
||||
)
|
||||
SELECT *
|
||||
FROM rw
|
||||
ORDER BY 1, 3;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 15:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## pump >< emp1 >< emp
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (empno, mgr, iters, sal) AS
|
||||
(
|
||||
SELECT e.empno, e.mgr, 1, e.sal
|
||||
FROM emp e, emp1 n1, emp1 n2
|
||||
WHERE e.empno = n1.empno and e.mgr = n2.empno and e.empno < e.mgr
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */r.empno, e.mgr, r.iters + 1, r.sal + e.sal
|
||||
FROM rw r, emp1 n, emp e
|
||||
WHERE r.mgr = e.empno and n.empno = e.mgr and e.empno < e.mgr
|
||||
)
|
||||
SELECT *
|
||||
FROM rw
|
||||
ORDER BY 1, 3;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 16:
|
||||
## - recursive WITH Query: Join Skew handling. No local filter
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ PQ_SKEW (r) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 17:
|
||||
## - recursive WITH Query: Join Skew handling with an additional local filter
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ PQ_SKEW (r) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr and e.empno < e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
CREATE TABLE tenk1 (
|
||||
unique1 int,
|
||||
unique2 int,
|
||||
two int,
|
||||
four int,
|
||||
ten int,
|
||||
twenty int,
|
||||
hundred int,
|
||||
thousand int,
|
||||
twothousand int,
|
||||
fivethous int,
|
||||
tenthous int,
|
||||
odd int,
|
||||
even int,
|
||||
stringu1 VARCHAR(50),
|
||||
stringu2 VARCHAR(50),
|
||||
string4 VARCHAR(50)
|
||||
);
|
||||
|
||||
WITH q1(x,y) AS (SELECT 1,2 FROM DUAL)
|
||||
SELECT * FROM q1, q1 q2;
|
||||
|
||||
SELECT count(*) FROM (
|
||||
WITH q1(x) AS (SELECT 1 FROM dual)
|
||||
SELECT * FROM q1
|
||||
UNION
|
||||
SELECT * FROM q1
|
||||
) ss;
|
||||
|
||||
CREATE TABLE department (
|
||||
id INTEGER PRIMARY KEY,
|
||||
parent_department INTEGER,
|
||||
name VARCHAR(100)
|
||||
);
|
||||
|
||||
INSERT INTO department VALUES (0, NULL, 'ROOT');
|
||||
INSERT INTO department VALUES (1, 0, 'A');
|
||||
INSERT INTO department VALUES (2, 1, 'B');
|
||||
INSERT INTO department VALUES (3, 2, 'C');
|
||||
INSERT INTO department VALUES (4, 2, 'D');
|
||||
INSERT INTO department VALUES (5, 0, 'E');
|
||||
INSERT INTO department VALUES (6, 4, 'F');
|
||||
INSERT INTO department VALUES (7, 5, 'G');
|
||||
|
||||
WITH subdepartment(lev, id, parent_department, name) AS
|
||||
(
|
||||
SELECT 1, a.* FROM department a WHERE name = 'A'
|
||||
UNION ALL
|
||||
SELECT sd.lev + 1, d.* FROM department d, subdepartment sd WHERE d.parent_department = sd.id
|
||||
)
|
||||
SELECT * FROM subdepartment ORDER BY name;
|
||||
|
||||
WITH subdepartment(lev, id, parent_department, name) AS
|
||||
(
|
||||
SELECT 1, a.* FROM department a WHERE name = 'A'
|
||||
UNION ALL
|
||||
SELECT sd.lev + 1, d.* FROM department d, subdepartment sd WHERE d.parent_department = sd.id
|
||||
)
|
||||
SELECT * FROM subdepartment WHERE lev >= 2 ORDER BY name;
|
||||
|
||||
WITH subdepartment AS
|
||||
(
|
||||
SELECT * FROM department WHERE name = 'A'
|
||||
)
|
||||
SELECT * FROM subdepartment ORDER BY name;
|
||||
|
||||
SELECT count(*) FROM (
|
||||
WITH t(n) AS (
|
||||
SELECT 1 FROM DUAL UNION ALL SELECT n + 1 FROM t WHERE n < 500
|
||||
)
|
||||
SELECT * FROM t) t WHERE n < (
|
||||
SELECT count(*) FROM (
|
||||
WITH t(n) AS (
|
||||
SELECT 1 FROM DUAL UNION ALL SELECT n + 1 FROM t WHERE n < 100
|
||||
)
|
||||
SELECT * FROM t WHERE n < 50000
|
||||
) t WHERE n < 100);
|
||||
|
||||
WITH q1(x,y) AS (
|
||||
SELECT hundred, sum(ten) FROM tenk1 GROUP BY hundred
|
||||
)
|
||||
SELECT count(*) FROM q1 WHERE y > (SELECT sum(y)/100 FROM q1 qsub);
|
||||
|
||||
WITH t(i,j) AS (
|
||||
select 1, 1 from dual
|
||||
UNION ALL
|
||||
SELECT t2.i, t.j+1 FROM (SELECT 2 AS i FROM DUAL UNION ALL SELECT 3 AS i FROM DUAL) t2 JOIN t ON (t2.i = t.i+1))
|
||||
SELECT * FROM t;
|
||||
|
||||
create table graph( f int, t int, label VARCHAR(50) );
|
||||
|
||||
insert into graph values
|
||||
(1, 2, 'arc 1 -> 2');
|
||||
insert into graph values
|
||||
(1, 3, 'arc 1 -> 3');
|
||||
insert into graph values
|
||||
(2, 3, 'arc 2 -> 3');
|
||||
insert into graph values
|
||||
(1, 4, 'arc 1 -> 4');
|
||||
insert into graph values
|
||||
(4, 5, 'arc 4 -> 5');
|
||||
insert into graph values
|
||||
(5, 1, 'arc 5 -> 1');
|
||||
|
||||
WITH
|
||||
y (id) AS (select 1 from dual),
|
||||
x (id) AS (SELECT * FROM y UNION ALL SELECT id+1 FROM x WHERE id < 5)
|
||||
SELECT * FROM x;
|
||||
|
||||
WITH
|
||||
x(id) AS
|
||||
(select 1 from dual UNION ALL SELECT id+1 FROM x WHERE id < 5),
|
||||
y(id) AS
|
||||
(select 1 from dual UNION ALL SELECT id+1 FROM y WHERE id < 10)
|
||||
SELECT y.*, x.* FROM y LEFT JOIN x on y.id = x.id;
|
||||
|
||||
WITH
|
||||
x(id) AS
|
||||
(select 1 from dual UNION ALL SELECT id+1 FROM x WHERE id < 5),
|
||||
y(id) AS
|
||||
(select 1 from dual UNION ALL SELECT id+1 FROM x WHERE id < 10)
|
||||
SELECT y.*, x.* FROM y LEFT JOIN x on y.id = x.id;
|
||||
|
||||
WITH
|
||||
x(id) AS
|
||||
(SELECT 1 FROM DUAL UNION ALL SELECT id+1 FROM x WHERE id < 3 ),
|
||||
y(id) AS
|
||||
(SELECT * FROM x UNION ALL SELECT * FROM x),
|
||||
z(id) AS
|
||||
(SELECT * FROM x UNION ALL SELECT id+1 FROM z WHERE id < 10)
|
||||
SELECT * FROM z;
|
||||
|
||||
WITH
|
||||
x(id) AS
|
||||
(SELECT 1 FROM DUAL UNION ALL SELECT id+1 FROM x WHERE id < 3 ),
|
||||
y(id) AS
|
||||
(SELECT * FROM x UNION ALL SELECT * FROM x),
|
||||
z(id) AS
|
||||
(SELECT * FROM y UNION ALL SELECT id+1 FROM z WHERE id < 10)
|
||||
SELECT * FROM z;
|
||||
|
||||
CREATE TABLE y (a INTEGER);
|
||||
insert into y values(1);
|
||||
insert into y values(2);
|
||||
insert into y values(3);
|
||||
insert into y values(4);
|
||||
insert into y values(5);
|
||||
insert into y values(6);
|
||||
insert into y values(7);
|
||||
insert into y values(8);
|
||||
insert into y values(9);
|
||||
insert into y values(10);
|
||||
|
||||
WITH x(n) AS (SELECT a FROM y WHERE a = 1
|
||||
UNION ALL
|
||||
SELECT x.n+1 FROM x LEFT JOIN y ON x.n = y.a WHERE n < 10)
|
||||
SELECT * FROM x;
|
||||
|
||||
WITH x(n) AS (SELECT a FROM y WHERE a = 1
|
||||
UNION ALL
|
||||
SELECT x.n+1 FROM y RIGHT JOIN x ON x.n = y.a WHERE n < 10)
|
||||
SELECT * FROM x;
|
||||
|
||||
WITH x(n) AS (SELECT 1 from dual UNION ALL SELECT count(*) FROM x)
|
||||
SELECT * FROM x;
|
||||
|
||||
WITH x(n) AS (SELECT 1 from dual UNION ALL SELECT sum(n) FROM x)
|
||||
SELECT * FROM x;
|
||||
|
||||
WITH x(n) AS (SELECT 1 from dual UNION ALL SELECT n+1 FROM x where n < 10 ORDER BY 1 ) SELECT * FROM x;
|
||||
WITH x(n) AS (SELECT 1 FROM DUAL UNION ALL SELECT n+1 FROM x where n < 10 FOR UPDATE)
|
||||
SELECT * FROM x;
|
||||
|
||||
CREATE TABLE x (n integer);
|
||||
with cte(foo) as ( select 42 from dual) select * from ((select foo from cte)) q;
|
||||
|
||||
select ( with cte(foo) as ( select 1 from dual )
|
||||
select (select foo from cte) from dual)
|
||||
from tenk1;
|
||||
|
||||
WITH outermost(x) AS (
|
||||
SELECT 1 FROM DUAL
|
||||
UNION (WITH innermost as (SELECT 2 FROM DUAL)
|
||||
SELECT * FROM innermost
|
||||
UNION SELECT 3 FROM DUAL)
|
||||
)
|
||||
SELECT * FROM outermost ORDER BY 1;
|
||||
|
||||
WITH outermost(x) AS (
|
||||
SELECT 1 FROM DUAL
|
||||
UNION (WITH innermost as (SELECT 2 FROM DUAL)
|
||||
SELECT * FROM outermost # fail
|
||||
UNION SELECT * FROM innermost)
|
||||
)
|
||||
SELECT * FROM outermost ORDER BY 1;
|
File diff suppressed because it is too large
Load Diff
1911
test/mysql_test/test_suite/with_clause/t/dis_recursive_mysql.test
Normal file
1911
test/mysql_test/test_suite/with_clause/t/dis_recursive_mysql.test
Normal file
File diff suppressed because it is too large
Load Diff
@ -0,0 +1,8 @@
|
||||
with cte1(c1, c2) as
|
||||
(select 1, '0' from dual
|
||||
union all select 2, '1' from dual
|
||||
),
|
||||
cte2(c1, c2) as
|
||||
(select '0', 1 from dual
|
||||
union all select cte1.c2, cte1.c1 from cte2, cte1 where 10 = cte2.c1)
|
||||
select * from cte1;
|
@ -0,0 +1,382 @@
|
||||
drop table EMP,DEPT,emp1,emp2;
|
||||
create table EMP (
|
||||
EMPno number,
|
||||
ENAME varchar(30),
|
||||
JOB varchar(30),
|
||||
MGR number(4),
|
||||
HIREDATE date,
|
||||
SAL number(7,2),
|
||||
COMM number(7,2),
|
||||
DEPTNO number(2)
|
||||
) ;
|
||||
|
||||
create table DEPT(
|
||||
DEPTNO number(2),
|
||||
DNAME(45),
|
||||
LOC varchar(39)
|
||||
) ;
|
||||
|
||||
CREATE TABLE emp1 (
|
||||
empno VARCHAR(4000) NOT NULL,
|
||||
ename VARCHAR(14),
|
||||
job VARCHAR(9),
|
||||
mgr VARCHAR(4000),
|
||||
hiredate DATE,
|
||||
sal NUMBER(7,2),
|
||||
comm NUMBER(7,2),
|
||||
deptno NUMBER(2));
|
||||
|
||||
CREATE TABLE emp2 (
|
||||
empno VARCHAR(4000) NOT NULL,
|
||||
ename VARCHAR(14),
|
||||
job VARCHAR(9),
|
||||
mgr VARCHAR(4000),
|
||||
hiredate DATE,
|
||||
sal NUMBER(7,2),
|
||||
comm NUMBER(7,2),
|
||||
deptno NUMBER(2));
|
||||
|
||||
insert into EMP values (7369,'SMITH','CLERK',7902, str_to_date('1980-12-17','%Y-%m-%d'),800,NULL, 20) ;
|
||||
INSERT INTO EMP VALUES (7499, 'ALLEN','SALESMAN',7698,str_to_date('1981-02-20','%Y-%m-%d'),1600,300,30) ;
|
||||
INSERT INTO EMP VALUES (7521,'WARD','SALESMAN',7698, str_to_date('1981-02-22','%Y-%m-%d'),1250, 500, 30) ;
|
||||
INSERT INTO EMP VALUES (7566,'JONES','MANAGER',7839, str_to_date('1981-08-02','%Y-%m-%d'), 2975, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES (7654,'MARTIN','SALESMAN', 7698, str_to_date('1981-09-28','%Y-%m-%d'), 1250, 1400, 30) ;
|
||||
INSERT INTO EMP VALUES (7698, 'BLAKE','MANAGER', 7839, str_to_date('1981-05-01','%Y-%m-%d'), 2850, NULL, 30) ;
|
||||
INSERT INTO EMP VALUES (7782, 'CLARK','MANAGER', 7839, str_to_date('1981-06-09','%Y-%m-%d'), 2450, NULL, 10) ;
|
||||
insert into EMP values (7788,'SCOTT','ANALYST', 7566, str_to_date('1987-08-19','%Y-%m-%d'), 3000, null, 20) ;
|
||||
INSERT INTO EMP VALUES (7839, 'KING','PRESIDENT', NULL, str_to_date('1981-11-17','%Y-%m-%d'), 5000, NULL, 10) ;
|
||||
INSERT INTO EMP VALUES (7844, 'TURNER','SALESMAN', 7698, str_to_date('1981-09-08','%Y-%m-%d'), 1500, 0, 30) ;
|
||||
INSERT INTO EMP VALUES(7876, 'ADAMS','CLERK', 7788, str_to_date('1987-05-23','%Y-%m-%d'), 1100, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES(7900, 'JAMES', 'CLEARK', 7698, str_to_date('1981-12-03','%Y-%m-%d'), 950, NULL, 30) ;
|
||||
INSERT INTO EMP VALUES(7902, 'FORD','ANALYST',7566, str_to_date('1981-12-03','%Y-%m-%d'), 3000, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES(7934,'MILLER','CLERK', 7782, str_to_date('1982-06-23','%Y-%m-%d'), 1300,NULL, 10) ;
|
||||
|
||||
|
||||
INSERT INTO emp1 values (7369, 'SMITH', 'CLERK', 7902, str_to_date('1980-12-17', '%Y-%m-%d'), 800, null, 20);
|
||||
INSERT INTO emp1 values (7499, 'ALLEN', 'SALESMAN', 7698, str_to_date('1981-02-20', '%Y-%m-%d'), 1600, 300, 30);
|
||||
INSERT INTO emp1 values (7521, 'WARD', 'SALESMAN', 7698, str_to_date('1981-02-22', '%Y-%m-%d'), 1250, 500, 30);
|
||||
INSERT INTO emp1 values (7566, 'JONES', 'MANAGER', 7839, str_to_date('1981-08-02', '%Y-%m-%d'), 2975, null, 20);
|
||||
INSERT INTO emp1 values (7654, 'MARTIN', 'SALESMAN', 7698, str_to_date('1981-09-28', '%Y-%m-%d'), 1250, 1400, 30);
|
||||
INSERT INTO emp1 values (7698, 'BLAKE', 'MANAGER', 7839, str_to_date('1981-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (7782, 'CLARK', 'MANAGER', 7839, str_to_date('1981-06-09' , '%Y-%m-%d'), 2450, null, 10);
|
||||
INSERT INTO emp1 values (7788, 'SCOTT', 'ANALYST', 7566, str_to_date('1987-08-19', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp1 values (7839, 'KING', 'PRESIDENT', null, str_to_date('1981-11-17', '%Y-%m-%d'), 5000, null, 10);
|
||||
INSERT INTO emp1 values (7844, 'TURNER', 'SALESMAN', 7698, str_to_date('1981-09-08', '%Y-%m-%d'), 1500, 0, 30);
|
||||
INSERT INTO emp1 values (7876, 'ADAMS', 'CLERK', 7788, str_to_date('1987-05-23', '%Y-%m-%d'), 1100, null, 20);
|
||||
INSERT INTO emp1 values (7900, 'JAMES', 'CLERK', 7698, str_to_date('1981-12-03', '%Y-%m-%d'), 950, null, 30);
|
||||
INSERT INTO emp1 values (7902, 'FORD', 'ANALYST', 7566, str_to_date('1981-12-03', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp1 values (7934, 'MILLER', 'CLERK', 7782, str_to_date('1982-01-23', '%Y-%m-%d'), 1300, null, 10);
|
||||
INSERT INTO emp1 values (LPAD('8100',400,'5'), 'Eve', 'MANAGER', 7839, str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8101',3000,'5'), 'Eve1', 'MANAGER', LPAD('8100',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8102',3000,'5'), 'Eve2', 'MANAGER', LPAD('8101',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8103',3000,'5'), 'Eve3', 'MANAGER', LPAD('8102',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8104',3000,'5'), 'Eve4', 'MANAGER', LPAD('8103',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8105',3000,'5'), 'Eve5', 'MANAGER', LPAD('8104',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8106',3000,'5'), 'Eve6', 'MANAGER', LPAD('8105',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8107',400,'5'), 'Eve7', 'MANAGER', LPAD('8106',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8108',400,'5'), 'Eve8', 'MANAGER', LPAD('8107',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8109',400,'5'), 'Eve9', 'MANAGER', LPAD('8108',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8110',400,'5'), 'Eve10', 'MANAGER', LPAD('8109',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8111',400,'5'), 'Eve11', 'MANAGER', LPAD('8110',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8112',400,'5'), 'Eve12', 'MANAGER', LPAD('8111',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8113',400,'5'), 'Eve13', 'MANAGER', LPAD('8112',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8114',400,'5'), 'Eve14', 'MANAGER', LPAD('8113',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8115',400,'5'), 'Eve15', 'MANAGER', LPAD('8114',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8116',400,'5'), 'Eve16', 'MANAGER', LPAD('8115',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8117',400,'5'), 'Eve17', 'MANAGER', LPAD('8116',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8118',400,'5'), 'Eve18', 'MANAGER', LPAD('8117',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8119',400,'5'), 'Eve19', 'CLERK', LPAD('8118',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
|
||||
INSERT INTO emp2 values (4002, 'SMITH', 'CLERK', 5002, str_to_date('1980-12-17', '%Y-%m-%d'), 800, null, 20);
|
||||
INSERT INTO emp2 values (5003, 'ALLEN', 'SALESMAN', 6002, str_to_date('1981-02-20', '%Y-%m-%d'), 1600, 300, 30);
|
||||
INSERT INTO emp2 values (5004, 'WARD', 'SALESMAN', 6002, str_to_date('1981-02-22', '%Y-%m-%d'), 1250, 500, 30);
|
||||
INSERT INTO emp2 values (6001, 'JONES', 'MANAGER', 7839, str_to_date('1981-08-02', '%Y-%m-%d'), 2975, null, 20);
|
||||
INSERT INTO emp2 values (5005, 'MARTIN', 'SALESMAN', 6002, str_to_date('1981-09-28', '%Y-%m-%d'), 1250, 1400, 30);
|
||||
INSERT INTO emp2 values (6002, 'BLAKE', 'MANAGER', 7839, str_to_date('1981-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp2 values (6003, 'CLARK', 'MANAGER', 7839, str_to_date('1981-06-09' , '%Y-%m-%d'), 2450, null, 10);
|
||||
INSERT INTO emp2 values (5001, 'SCOTT', 'ANALYST', 6001, str_to_date('1987-08-19', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp2 values (7839, 'KING', 'PRESIDENT', null, str_to_date('1987-11-17', '%Y-%m-%d'), 5000, null, 10);
|
||||
INSERT INTO emp2 values (5006, 'TURNER', 'SALESMAN', 6002, str_to_date('1981-09-08', '%Y-%m-%d'), 1500, 0, 30);
|
||||
INSERT INTO emp2 values (4001, 'ADAMS', 'CLERK', 5001, str_to_date('1987-05-23', '%Y-%m-%d'), 1100, null, 20);
|
||||
INSERT INTO emp2 values (5007, 'JAMES', 'CLERK', 6002, str_to_date('1981-12-03', '%Y-%m-%d'), 950, null, 30);
|
||||
INSERT INTO emp2 values (5002, 'FORD', 'ANALYST', 6001, str_to_date('1981-12-03', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp2 values (5008, 'MILLER', 'CLERK', 6003, str_to_date('1982-01-23', '%Y-%m-%d'), 1300, null, 10);
|
||||
|
||||
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 1:
|
||||
## - recursive WITH Query: no cycle clause used in query in acyclic data
|
||||
## =======================================================================
|
||||
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
|
||||
update emp set mgr = 7788 where ename = 'KING';
|
||||
|
||||
drop table emp1;
|
||||
drop table emp2;
|
||||
|
||||
CREATE TABLE emp1 (
|
||||
empno VARCHAR(4000) NOT NULL,
|
||||
ename VARCHAR(14),
|
||||
job VARCHAR(9),
|
||||
mgr VARCHAR(4000),
|
||||
hiredate DATE,
|
||||
sal NUMBER(7,2),
|
||||
comm NUMBER(7,2),
|
||||
deptno NUMBER(2));
|
||||
|
||||
CREATE TABLE emp2 (
|
||||
empno VARCHAR(4000) NOT NULL,
|
||||
ename VARCHAR(14),
|
||||
job VARCHAR(9),
|
||||
mgr VARCHAR(4000),
|
||||
hiredate DATE,
|
||||
sal NUMBER(7,2),
|
||||
comm NUMBER(7,2),
|
||||
deptno NUMBER(2));
|
||||
|
||||
INSERT INTO emp1 values (7369, 'SMITH', 'CLERK', 7902, str_to_date('1980-12-17', '%Y-%m-%d'), 800, null, 20);
|
||||
INSERT INTO emp1 values (7499, 'ALLEN', 'SALESMAN', 7698, str_to_date('1981-02-20', '%Y-%m-%d'), 1600, 300, 30);
|
||||
INSERT INTO emp1 values (7521, 'WARD', 'SALESMAN', 7698, str_to_date('1981-02-22', '%Y-%m-%d'), 1250, 500, 30);
|
||||
INSERT INTO emp1 values (7566, 'JONES', 'MANAGER', 7839, str_to_date('1981-08-02', '%Y-%m-%d'), 2975, null, 20);
|
||||
INSERT INTO emp1 values (7654, 'MARTIN', 'SALESMAN', 7698, str_to_date('1981-09-28', '%Y-%m-%d'), 1250, 1400, 30);
|
||||
INSERT INTO emp1 values (7698, 'BLAKE', 'MANAGER', 7839, str_to_date('1981-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (7782, 'CLARK', 'MANAGER', 7839, str_to_date('1981-06-09' , '%Y-%m-%d'), 2450, null, 10);
|
||||
INSERT INTO emp1 values (7788, 'SCOTT', 'ANALYST', 7566, str_to_date('1987-08-19', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp1 values (7839, 'KING', 'PRESIDENT', null, str_to_date('1981-11-17', '%Y-%m-%d'), 5000, null, 10);
|
||||
INSERT INTO emp1 values (7844, 'TURNER', 'SALESMAN', 7698, str_to_date('1981-09-08', '%Y-%m-%d'), 1500, 0, 30);
|
||||
INSERT INTO emp1 values (7876, 'ADAMS', 'CLERK', 7788, str_to_date('1987-05-23', '%Y-%m-%d'), 1100, null, 20);
|
||||
INSERT INTO emp1 values (7900, 'JAMES', 'CLERK', 7698, str_to_date('1981-12-03', '%Y-%m-%d'), 950, null, 30);
|
||||
INSERT INTO emp1 values (7902, 'FORD', 'ANALYST', 7566, str_to_date('1981-12-03', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp1 values (7934, 'MILLER', 'CLERK', 7782, str_to_date('1982-01-23', '%Y-%m-%d'), 1300, null, 10);
|
||||
INSERT INTO emp1 values (LPAD('8100',400,'5'), 'Eve', 'MANAGER', 7839, str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8101',3000,'5'), 'Eve1', 'MANAGER', LPAD('8100',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8102',3000,'5'), 'Eve2', 'MANAGER', LPAD('8101',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8103',3000,'5'), 'Eve3', 'MANAGER', LPAD('8102',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8104',3000,'5'), 'Eve4', 'MANAGER', LPAD('8103',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8105',3000,'5'), 'Eve5', 'MANAGER', LPAD('8104',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8106',3000,'5'), 'Eve6', 'MANAGER', LPAD('8105',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8107',400,'5'), 'Eve7', 'MANAGER', LPAD('8106',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8108',400,'5'), 'Eve8', 'MANAGER', LPAD('8107',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8109',400,'5'), 'Eve9', 'MANAGER', LPAD('8108',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8110',400,'5'), 'Eve10', 'MANAGER', LPAD('8109',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8111',400,'5'), 'Eve11', 'MANAGER', LPAD('8110',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8112',400,'5'), 'Eve12', 'MANAGER', LPAD('8111',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8113',400,'5'), 'Eve13', 'MANAGER', LPAD('8112',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8114',400,'5'), 'Eve14', 'MANAGER', LPAD('8113',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8115',400,'5'), 'Eve15', 'MANAGER', LPAD('8114',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8116',400,'5'), 'Eve16', 'MANAGER', LPAD('8115',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8117',400,'5'), 'Eve17', 'MANAGER', LPAD('8116',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8118',400,'5'), 'Eve18', 'MANAGER', LPAD('8117',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8119',400,'5'), 'Eve19', 'CLERK', LPAD('8118',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
|
||||
INSERT INTO emp2 values (4002, 'SMITH', 'CLERK', 5002, str_to_date('1980-12-17', '%Y-%m-%d'), 800, null, 20);
|
||||
INSERT INTO emp2 values (5003, 'ALLEN', 'SALESMAN', 6002, str_to_date('1981-02-20', '%Y-%m-%d'), 1600, 300, 30);
|
||||
INSERT INTO emp2 values (5004, 'WARD', 'SALESMAN', 6002, str_to_date('1981-02-22', '%Y-%m-%d'), 1250, 500, 30);
|
||||
INSERT INTO emp2 values (6001, 'JONES', 'MANAGER', 7839, str_to_date('1981-08-02', '%Y-%m-%d'), 2975, null, 20);
|
||||
INSERT INTO emp2 values (5005, 'MARTIN', 'SALESMAN', 6002, str_to_date('1981-09-28', '%Y-%m-%d'), 1250, 1400, 30);
|
||||
INSERT INTO emp2 values (6002, 'BLAKE', 'MANAGER', 7839, str_to_date('1981-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp2 values (6003, 'CLARK', 'MANAGER', 7839, str_to_date('1981-06-09' , '%Y-%m-%d'), 2450, null, 10);
|
||||
INSERT INTO emp2 values (5001, 'SCOTT', 'ANALYST', 6001, str_to_date('1987-08-19', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp2 values (7839, 'KING', 'PRESIDENT', null, str_to_date('1987-11-17', '%Y-%m-%d'), 5000, null, 10);
|
||||
INSERT INTO emp2 values (5006, 'TURNER', 'SALESMAN', 6002, str_to_date('1981-09-08', '%Y-%m-%d'), 1500, 0, 30);
|
||||
INSERT INTO emp2 values (4001, 'ADAMS', 'CLERK', 5001, str_to_date('1987-05-23', '%Y-%m-%d'), 1100, null, 20);
|
||||
INSERT INTO emp2 values (5007, 'JAMES', 'CLERK', 6002, str_to_date('1981-12-03', '%Y-%m-%d'), 950, null, 30);
|
||||
INSERT INTO emp2 values (5002, 'FORD', 'ANALYST', 6001, str_to_date('1981-12-03', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp2 values (5008, 'MILLER', 'CLERK', 6003, str_to_date('1982-01-23', '%Y-%m-%d'), 1300, null, 10);
|
||||
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 2:
|
||||
## - recursive WITH Query(Negative): cycle clause not used in query with
|
||||
## cyclic data
|
||||
## =======================================================================
|
||||
|
||||
/* add loop from scott back to king in emp */
|
||||
update emp set mgr = 7788 where ename = 'KING';
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
|
||||
drop table emp1;
|
||||
drop table emp2;
|
||||
|
||||
CREATE TABLE emp1 (
|
||||
empno VARCHAR(4000) NOT NULL,
|
||||
ename VARCHAR(14),
|
||||
job VARCHAR(9),
|
||||
mgr VARCHAR(4000),
|
||||
hiredate DATE,
|
||||
sal NUMBER(7,2),
|
||||
comm NUMBER(7,2),
|
||||
deptno NUMBER(2));
|
||||
|
||||
CREATE TABLE emp2 (
|
||||
empno VARCHAR(4000) NOT NULL,
|
||||
ename VARCHAR(14),
|
||||
job VARCHAR(9),
|
||||
mgr VARCHAR(4000),
|
||||
hiredate DATE,
|
||||
sal NUMBER(7,2),
|
||||
comm NUMBER(7,2),
|
||||
deptno NUMBER(2));
|
||||
|
||||
INSERT INTO emp1 values (7369, 'SMITH', 'CLERK', 7902, str_to_date('1980-12-17', '%Y-%m-%d'), 800, null, 20);
|
||||
INSERT INTO emp1 values (7499, 'ALLEN', 'SALESMAN', 7698, str_to_date('1981-02-20', '%Y-%m-%d'), 1600, 300, 30);
|
||||
INSERT INTO emp1 values (7521, 'WARD', 'SALESMAN', 7698, str_to_date('1981-02-22', '%Y-%m-%d'), 1250, 500, 30);
|
||||
INSERT INTO emp1 values (7566, 'JONES', 'MANAGER', 7839, str_to_date('1981-08-02', '%Y-%m-%d'), 2975, null, 20);
|
||||
INSERT INTO emp1 values (7654, 'MARTIN', 'SALESMAN', 7698, str_to_date('1981-09-28', '%Y-%m-%d'), 1250, 1400, 30);
|
||||
INSERT INTO emp1 values (7698, 'BLAKE', 'MANAGER', 7839, str_to_date('1981-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (7782, 'CLARK', 'MANAGER', 7839, str_to_date('1981-06-09' , '%Y-%m-%d'), 2450, null, 10);
|
||||
INSERT INTO emp1 values (7788, 'SCOTT', 'ANALYST', 7566, str_to_date('1987-08-19', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp1 values (7839, 'KING', 'PRESIDENT', null, str_to_date('1981-11-17', '%Y-%m-%d'), 5000, null, 10);
|
||||
INSERT INTO emp1 values (7844, 'TURNER', 'SALESMAN', 7698, str_to_date('1981-09-08', '%Y-%m-%d'), 1500, 0, 30);
|
||||
INSERT INTO emp1 values (7876, 'ADAMS', 'CLERK', 7788, str_to_date('1987-05-23', '%Y-%m-%d'), 1100, null, 20);
|
||||
INSERT INTO emp1 values (7900, 'JAMES', 'CLERK', 7698, str_to_date('1981-12-03', '%Y-%m-%d'), 950, null, 30);
|
||||
INSERT INTO emp1 values (7902, 'FORD', 'ANALYST', 7566, str_to_date('1981-12-03', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp1 values (7934, 'MILLER', 'CLERK', 7782, str_to_date('1982-01-23', '%Y-%m-%d'), 1300, null, 10);
|
||||
INSERT INTO emp1 values (LPAD('8100',400,'5'), 'Eve', 'MANAGER', 7839, str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8101',3000,'5'), 'Eve1', 'MANAGER', LPAD('8100',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8102',3000,'5'), 'Eve2', 'MANAGER', LPAD('8101',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8103',3000,'5'), 'Eve3', 'MANAGER', LPAD('8102',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8104',3000,'5'), 'Eve4', 'MANAGER', LPAD('8103',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8105',3000,'5'), 'Eve5', 'MANAGER', LPAD('8104',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8106',3000,'5'), 'Eve6', 'MANAGER', LPAD('8105',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8107',400,'5'), 'Eve7', 'MANAGER', LPAD('8106',3000,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8108',400,'5'), 'Eve8', 'MANAGER', LPAD('8107',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8109',400,'5'), 'Eve9', 'MANAGER', LPAD('8108',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8110',400,'5'), 'Eve10', 'MANAGER', LPAD('8109',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8111',400,'5'), 'Eve11', 'MANAGER', LPAD('8110',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8112',400,'5'), 'Eve12', 'MANAGER', LPAD('8111',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8113',400,'5'), 'Eve13', 'MANAGER', LPAD('8112',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8114',400,'5'), 'Eve14', 'MANAGER', LPAD('8113',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8115',400,'5'), 'Eve15', 'MANAGER', LPAD('8114',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8116',400,'5'), 'Eve16', 'MANAGER', LPAD('8115',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8117',400,'5'), 'Eve17', 'MANAGER', LPAD('8116',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8118',400,'5'), 'Eve18', 'MANAGER', LPAD('8117',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (LPAD('8119',400,'5'), 'Eve19', 'CLERK', LPAD('8118',400,'5'), str_to_date('1984-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
|
||||
INSERT INTO emp2 values (4002, 'SMITH', 'CLERK', 5002, str_to_date('1980-12-17', '%Y-%m-%d'), 800, null, 20);
|
||||
INSERT INTO emp2 values (5003, 'ALLEN', 'SALESMAN', 6002, str_to_date('1981-02-20', '%Y-%m-%d'), 1600, 300, 30);
|
||||
INSERT INTO emp2 values (5004, 'WARD', 'SALESMAN', 6002, str_to_date('1981-02-22', '%Y-%m-%d'), 1250, 500, 30);
|
||||
INSERT INTO emp2 values (6001, 'JONES', 'MANAGER', 7839, str_to_date('1981-08-02', '%Y-%m-%d'), 2975, null, 20);
|
||||
INSERT INTO emp2 values (5005, 'MARTIN', 'SALESMAN', 6002, str_to_date('1981-09-28', '%Y-%m-%d'), 1250, 1400, 30);
|
||||
INSERT INTO emp2 values (6002, 'BLAKE', 'MANAGER', 7839, str_to_date('1981-05-01', '%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp2 values (6003, 'CLARK', 'MANAGER', 7839, str_to_date('1981-06-09' , '%Y-%m-%d'), 2450, null, 10);
|
||||
INSERT INTO emp2 values (5001, 'SCOTT', 'ANALYST', 6001, str_to_date('1987-08-19', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp2 values (7839, 'KING', 'PRESIDENT', null, str_to_date('1987-11-17', '%Y-%m-%d'), 5000, null, 10);
|
||||
INSERT INTO emp2 values (5006, 'TURNER', 'SALESMAN', 6002, str_to_date('1981-09-08', '%Y-%m-%d'), 1500, 0, 30);
|
||||
INSERT INTO emp2 values (4001, 'ADAMS', 'CLERK', 5001, str_to_date('1987-05-23', '%Y-%m-%d'), 1100, null, 20);
|
||||
INSERT INTO emp2 values (5007, 'JAMES', 'CLERK', 6002, str_to_date('1981-12-03', '%Y-%m-%d'), 950, null, 30);
|
||||
INSERT INTO emp2 values (5002, 'FORD', 'ANALYST', 6001, str_to_date('1981-12-03', '%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp2 values (5008, 'MILLER', 'CLERK', 6003, str_to_date('1982-01-23', '%Y-%m-%d'), 1300, null, 10);
|
||||
|
||||
|
||||
update emp2 set mgr = 5001 where ename = 'KING';
|
||||
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 3:
|
||||
## - recursive WITH Query: Cycle Pruning with Cycle clause not used in the query
|
||||
## Pruning predicate added that results in no cycles e.mgr < e.empno
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp2 e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp2 e
|
||||
WHERE r.empno = e.mgr and e.mgr < e.empno
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 4:
|
||||
## - recursive WITH Query: Cycle Pruning with Cycle clause not used in the query
|
||||
## Pruning predicate added that results in no cycles e.mgr > e.empno
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp2 e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp2 e
|
||||
WHERE r.empno = e.mgr and e.mgr > e.empno
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 5:
|
||||
## - recursive WITH Query: Cycle Pruning with Cycle clause not used in the query
|
||||
## Pruning predicate added that results in no cycles r.empno < e.empno
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp2 e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp2 e
|
||||
WHERE r.empno = e.mgr and r.empno < e.empno
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 6:
|
||||
## - recursive WITH Query: Cycle Pruning with Cycle clause not used in the query
|
||||
## Pruning predicate added that results in no cycles r.empno > e.empno
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp2 e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp2 e
|
||||
WHERE r.empno = e.mgr and r.empno > e.empno
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
|
||||
|
||||
|
||||
|
@ -0,0 +1,375 @@
|
||||
drop table EMP;
|
||||
create table EMP (
|
||||
EMPno number,
|
||||
ENAME VARCHAR(30),
|
||||
JOB VARCHAR(30),
|
||||
MGR number(4),
|
||||
HIREDATE date,
|
||||
SAL number(7,2),
|
||||
COMM number(7,2),
|
||||
DEPTNO number(2)
|
||||
) ;
|
||||
|
||||
INSERT INTO EMP values (7369,'SMITH','CLERK',7902, str_to_date('1980-12-17','%Y-%m-%d'),800,NULL, 20) ;
|
||||
INSERT INTO EMP VALUES (7499, 'ALLEN','SALESMAN',7698,str_to_date('1981-02-20','%Y-%m-%d'),1600,300,30) ;
|
||||
INSERT INTO EMP VALUES (7521,'WARD','SALESMAN',7698, str_to_date('1981-02-22','%Y-%m-%d'),1250, 500, 30) ;
|
||||
INSERT INTO EMP VALUES (7566,'JONES','MANAGER',7839, str_to_date('1981-08-02','%Y-%m-%d'), 2975, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES (7654,'MARTIN','SALESMAN', 7698, str_to_date('1981-09-28','%Y-%m-%d'), 1250, 1400, 30) ;
|
||||
INSERT INTO EMP VALUES (7698, 'BLAKE','MANAGER', 7839, str_to_date('1981-05-01','%Y-%m-%d'), 2850, NULL, 30) ;
|
||||
INSERT INTO EMP VALUES (7782, 'CLARK','MANAGER', 7839, str_to_date('1981-06-09','%Y-%m-%d'), 2450, NULL, 10) ;
|
||||
insert into EMP values (7788,'SCOTT','ANALYST', 7566, str_to_date('1987-08-19','%Y-%m-%d'), 3000, null, 20) ;
|
||||
INSERT INTO EMP VALUES (7839, 'KING','PRESIDENT', NULL, str_to_date('1981-11-17','%Y-%m-%d'), 5000, NULL, 10) ;
|
||||
INSERT INTO EMP VALUES (7844, 'TURNER','SALESMAN', 7698, str_to_date('1981-09-08','%Y-%m-%d'), 1500, 0, 30) ;
|
||||
INSERT INTO EMP VALUES(7876, 'ADAMS','CLERK', 7788, str_to_date('1987-05-23','%Y-%m-%d'), 1100, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES(7900, 'JAMES', 'CLEARK', 7698, str_to_date('1981-12-03','%Y-%m-%d'), 950, NULL, 30) ;
|
||||
INSERT INTO EMP VALUES(7902, 'FORD','ANALYST',7566, str_to_date('1981-12-03','%Y-%m-%d'), 3000, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES(7934,'MILLER','CLERK', 7782, str_to_date('1982-01-23','%Y-%m-%d'), 1300,NULL, 10) ;
|
||||
|
||||
drop table emp1;
|
||||
CREATE TABLE emp1 (
|
||||
empno VARCHAR(4000) NOT NULL,
|
||||
ename VARCHAR(14),
|
||||
job VARCHAR(9),
|
||||
mgr VARCHAR(4000),
|
||||
hiredate DATE,
|
||||
sal NUMBER(7,2),
|
||||
comm NUMBER(7,2),
|
||||
deptno NUMBER(2));
|
||||
|
||||
INSERT INTO emp1 values (7369, 'SMITH', 'CLERK', 7902, str_to_date('1980-12-17',
|
||||
'%Y-%m-%d'), 800, null, 20);
|
||||
INSERT INTO emp1 values (7499, 'ALLEN', 'SALESMAN', 7698, str_to_date('1981-02-20', '%Y-%m-%d'), 1600, 300, 30);
|
||||
INSERT INTO emp1 values (7521, 'WARD', 'SALESMAN', 7698, str_to_date('1981-02-22',
|
||||
'%Y-%m-%d'), 1250, 500, 30);
|
||||
INSERT INTO emp1 values (7566, 'JONES', 'MANAGER', 7839, str_to_date('1981-08-02',
|
||||
'%Y-%m-%d'), 2975, null, 20);
|
||||
INSERT INTO emp1 values (7654, 'MARTIN', 'SALESMAN', 7698, str_to_date('1981-09-28', '%Y-%m-%d'), 1250, 1400, 30);
|
||||
INSERT INTO emp1 values (7698, 'BLAKE', 'MANAGER', 7839, str_to_date('1981-05-01',
|
||||
'%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (7782, 'CLARK', 'MANAGER', 7839, str_to_date('1981-06-09'
|
||||
, '%Y-%m-%d'), 2450, null, 10);
|
||||
INSERT INTO emp1 values (7788, 'SCOTT', 'ANALYST', 7566, str_to_date('1987-08-19',
|
||||
'%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp1 values (7839, 'KING', 'PRESIDENT', null, str_to_date('1981-11-17', '%Y-%m-%d'), 5000, null, 10);
|
||||
INSERT INTO emp1 values (7844, 'TURNER', 'SALESMAN', 7698, str_to_date('1981-09-08', '%Y-%m-%d'), 1500, 0, 30);
|
||||
INSERT INTO emp1 values (7876, 'ADAMS', 'CLERK', 7788, str_to_date('1987-05-23',
|
||||
'%Y-%m-%d'), 1100, null, 20);
|
||||
INSERT INTO emp1 values (7900, 'JAMES', 'CLERK', 7698, str_to_date('1981-12-03',
|
||||
'%Y-%m-%d'), 950, null, 30);
|
||||
INSERT INTO emp1 values (7902, 'FORD', 'ANALYST', 7566, str_to_date('1981-12-03',
|
||||
'%Y-%m-%d'), 3000, null, 20);
|
||||
INSERT INTO emp1 values (7934, 'MILLER', 'CLERK', 7782, str_to_date('1982-01-23',
|
||||
'%Y-%m-%d'), 1300, null, 10);
|
||||
|
||||
INSERT INTO emp1 values (8100, 'Eve', 'MANAGER', 7839, str_to_date('1984-05-01',
|
||||
'%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (8101, 'Eve1', 'MANAGER', 8100, str_to_date('1984-05-01',
|
||||
'%Y-%m-%d'), 2850, null, 30);
|
||||
INSERT INTO emp1 values (8108, 'Eve8', 'CLERK', 8101, str_to_date('1984-05-01',
|
||||
'%Y-%m-%d'), 2850, null, 30);
|
||||
|
||||
result_format: 4
|
||||
## =======================================================================
|
||||
## Test Case 1:
|
||||
## - recursive WITH Query: Nested Loop Join
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ USE_NL(r e) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 2:
|
||||
## - recursive WITH Query: SORT MERGE Join
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ USE_MERGE(r e) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 3:
|
||||
## - recursive WITH Query: Hash Join
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ USE_HASH(r e) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 4:
|
||||
## - recursive WITH Query: Join in Initialisation Branch
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT /*+ USE_NL(e d) */ e.ename, e.mgr, e.empno
|
||||
FROM emp e, emp d
|
||||
WHERE e.sal = d. sal
|
||||
UNION ALL
|
||||
SELECT /*+ USE_HASH(r e) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e, emp d
|
||||
WHERE r.empno = e.mgr and e.sal = d.sal
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 6:
|
||||
## - recursive WITH Query: Hash Join without using hints
|
||||
## Static input on build side and fits in memory
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno
|
||||
FROM emp e, rw r
|
||||
WHERE e.mgr = r.empno
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 7:
|
||||
## - recursive WITH Query: Hash Join without using hints
|
||||
## Static input on probe side and fits in memory
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## 测试8-15都是在测试join的顺序或者hint的顺序
|
||||
## Test Case 8:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## pump >< emp >< emp1
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (empno, mgr, iters, sal) AS
|
||||
(
|
||||
SELECT e.empno, e.mgr, 1, e.sal
|
||||
FROM emp e, emp1 n1, emp1 n2
|
||||
WHERE e.empno = n1.empno and e.mgr = n2.empno and e.empno < e.mgr
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */r.empno, e.mgr, r.iters + 1, r.sal + e.sal
|
||||
FROM rw r, emp e, emp1 n
|
||||
WHERE r.mgr = e.empno and e.mgr = n.empno and e.empno < e.mgr
|
||||
)
|
||||
SELECT *
|
||||
FROM rw
|
||||
ORDER BY 1, 3;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 9:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## emp >< pump >< emp1
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (empno, mgr, iters, sal) AS
|
||||
(
|
||||
SELECT e.empno, e.mgr, 1, e.sal
|
||||
FROM emp e, emp1 n1, emp1 n2
|
||||
WHERE e.empno = n1.empno and e.mgr = n2.empno and e.empno < e.mgr
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */r.empno, e.mgr, r.iters + 1, r.sal + e.sal
|
||||
FROM emp e, rw r, emp1 n
|
||||
WHERE e.empno = r.mgr and e.mgr = n.empno and e.empno < e.mgr
|
||||
)
|
||||
SELECT *
|
||||
FROM rw
|
||||
ORDER BY 1, 3;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 10:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## emp >< emp1 >< pump
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (empno, mgr, iters, sal) AS
|
||||
(
|
||||
SELECT e.empno, e.mgr, 1, e.sal
|
||||
FROM emp e, emp1 n1, emp1 n2
|
||||
WHERE e.empno = n1.empno and e.mgr = n2.empno and e.empno < e.mgr
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */r.empno, e.mgr, r.iters + 1, r.sal + e.sal
|
||||
FROM emp e, emp1 n, rw r
|
||||
WHERE e.mgr = n.empno and e.empno = r.mgr and e.empno < e.mgr
|
||||
)
|
||||
SELECT *
|
||||
FROM rw
|
||||
ORDER BY 1, 3;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 11:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## emp1 >< emp >< pump
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (empno, mgr, iters, sal) AS
|
||||
(
|
||||
SELECT e.empno, e.mgr, 1, e.sal
|
||||
FROM emp e, emp1 n1, emp1 n2
|
||||
WHERE e.empno = n1.empno and e.mgr = n2.empno and e.empno < e.mgr
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */r.empno, e.mgr, r.iters + 1, r.sal + e.sal
|
||||
FROM emp1 n, emp e, rw r
|
||||
WHERE n.empno = e.mgr and e.empno = r.mgr and e.empno < e.mgr
|
||||
)
|
||||
SELECT *
|
||||
FROM rw
|
||||
ORDER BY 1, 3;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 12:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## pump >< emp
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 13:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## emp >< pump
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */ e.ename, e.mgr, e.empno
|
||||
FROM emp e, rw r
|
||||
WHERE e.mgr = r.empno
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 14:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## emp1 >< pump >< emp
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (empno, mgr, iters, sal) AS
|
||||
(
|
||||
SELECT e.empno, e.mgr, 1, e.sal
|
||||
FROM emp e, emp1 n1, emp1 n2
|
||||
WHERE e.empno = n1.empno and e.mgr = n2.empno and e.empno < e.mgr
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */r.empno, e.mgr, r.iters + 1, r.sal + e.sal
|
||||
FROM emp1 n, rw r, emp e
|
||||
WHERE n.empno = e.mgr and r.mgr = e.empno and e.empno < e.mgr
|
||||
)
|
||||
SELECT *
|
||||
FROM rw
|
||||
ORDER BY 1, 3;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 15:
|
||||
## - recursive WITH Query: Join Order tests
|
||||
## pump >< emp1 >< emp
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (empno, mgr, iters, sal) AS
|
||||
(
|
||||
SELECT e.empno, e.mgr, 1, e.sal
|
||||
FROM emp e, emp1 n1, emp1 n2
|
||||
WHERE e.empno = n1.empno and e.mgr = n2.empno and e.empno < e.mgr
|
||||
UNION ALL
|
||||
SELECT /*+ ORDERED USE_HASH (r e) */r.empno, e.mgr, r.iters + 1, r.sal + e.sal
|
||||
FROM rw r, emp1 n, emp e
|
||||
WHERE r.mgr = e.empno and n.empno = e.mgr and e.empno < e.mgr
|
||||
)
|
||||
SELECT *
|
||||
FROM rw
|
||||
ORDER BY 1, 3;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 16:
|
||||
## - recursive WITH Query: Join Skew handling. No local filter
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ PQ_SKEW (r) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 17:
|
||||
## - recursive WITH Query: Join Skew handling with an additional local filter
|
||||
## =======================================================================
|
||||
|
||||
WITH rw (ename, mgr, empno) AS
|
||||
(
|
||||
SELECT ename, mgr, empno
|
||||
FROM emp e
|
||||
WHERE job = 'PRESIDENT'
|
||||
UNION ALL
|
||||
SELECT /*+ PQ_SKEW (r) */ e.ename, e.mgr, e.empno
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr and e.empno < e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr
|
||||
FROM rw;
|
524
test/mysql_test/test_suite/with_clause/t/recursive_mysql.test
Normal file
524
test/mysql_test/test_suite/with_clause/t/recursive_mysql.test
Normal file
@ -0,0 +1,524 @@
|
||||
drop table emp;
|
||||
create table emp (id int, name varchar(20), leaderid int);
|
||||
insert into emp values(1, 'A', '0');
|
||||
insert into emp values(2, 'AA', '1');
|
||||
insert into emp values(3, 'AB', '1');
|
||||
insert into emp values(4, 'ABA', '3');
|
||||
insert into emp values(5, 'AAA', '2');
|
||||
insert into emp values(6, 'ABB', '3');
|
||||
insert into emp values(7, 'AAA', '5');
|
||||
insert into emp values(8, 'AAA', '7');
|
||||
insert into emp values(9, 'AAAA', '5');
|
||||
insert into emp values(10, 'AAAB', '5');
|
||||
insert into emp values(11, 'AAAC', '5');
|
||||
insert into emp values(12, 'AAAA', '5');
|
||||
|
||||
drop table dsemp;
|
||||
create table dsemp (id int, name varchar(20), leaderid int) partition by hash (id) partitions 3;
|
||||
insert into dsemp values(1, 'A', '0');
|
||||
insert into dsemp values(2, 'AA', '1');
|
||||
insert into dsemp values(3, 'AB', '1');
|
||||
insert into dsemp values(4, 'ABA', '3');
|
||||
insert into dsemp values(5, 'AAA', '2');
|
||||
insert into dsemp values(6, 'ABB', '3');
|
||||
insert into dsemp values(7, 'AAA', '5');
|
||||
insert into dsemp values(8, 'AAA', '7');
|
||||
insert into dsemp values(9, 'AAAA', '5');
|
||||
insert into dsemp values(10, 'AAAB', '5');
|
||||
insert into dsemp values(11, 'AAAC', '5');
|
||||
insert into dsemp values(12, 'AAAA', '5');
|
||||
|
||||
drop table t1;
|
||||
create table t1(c1 int, c2 int, c3 int);
|
||||
insert into t1 values(1, 2, 3);
|
||||
insert into t1 values(4, 5, 6);
|
||||
insert into t1 values(7, 8, 9);
|
||||
insert into t1 values(10, 11, 12);
|
||||
insert into t1 values(13, 14, 15);
|
||||
insert into t1 values(16, 17, 18);
|
||||
insert into t1 values(19, 20, 21);
|
||||
|
||||
drop table t2;
|
||||
create table t2 (c1 int, c2 int, c3 int);
|
||||
insert into t2 values(1,1,3);
|
||||
insert into t2 values(2,2,3);
|
||||
insert into t2 values(3,3,3);
|
||||
insert into t2 values(4,4,3);
|
||||
insert into t2 values(5,5,3);
|
||||
|
||||
drop table t44;
|
||||
create table t44 (c1 int, c2 int, c3 int);
|
||||
insert into t44 values(1,1,3);
|
||||
insert into t44 values(2,2,3);
|
||||
insert into t44 values(3,3,3);
|
||||
|
||||
drop table insert_t;
|
||||
create table insert_t (c1 int, c2 int, c3 int);
|
||||
|
||||
drop table t3;
|
||||
create table t3(c1 int primary key, c2 int, c3 varchar(32)) partition by hash (c1) partitions 3;
|
||||
|
||||
drop table troot;
|
||||
create table troot(c1 int primary key, c2 int, c3 int unique);
|
||||
insert into troot values(1, 0, -1);
|
||||
insert into troot values(2, 1, -2);
|
||||
insert into troot values(3, 1, -3);
|
||||
insert into troot values(4, 2, -4);
|
||||
insert into troot values(5, 2, -5);
|
||||
insert into troot values(6, 2, -6);
|
||||
insert into troot values(7, 3, -7);
|
||||
insert into troot values(8, 3, -8);
|
||||
insert into troot values(9, 1, -9);
|
||||
insert into troot values(10, 9, -10);
|
||||
insert into troot values(11, 10, -11);
|
||||
insert into troot values(12, 7, -12);
|
||||
insert into troot values(13, 4, -13);
|
||||
|
||||
drop table t4;
|
||||
create table t4(id int, value char(10), parent_id int);
|
||||
insert into t4 values(1, 'A', NULL);
|
||||
insert into t4 values(2, 'B', 1);
|
||||
insert into t4 values(3, 'C', 1);
|
||||
insert into t4 values(4, 'D', 1);
|
||||
insert into t4 values(5, 'E', 2);
|
||||
insert into t4 values(6, 'F', 2);
|
||||
insert into t4 values(7, 'G', 4);
|
||||
insert into t4 values(8, 'H', 6);
|
||||
|
||||
drop table z;
|
||||
create table z(zc int);
|
||||
insert into z values(1);
|
||||
insert into z values(2);
|
||||
insert into z values(3);
|
||||
insert into z values(4);
|
||||
insert into z values(5);
|
||||
insert into z values(6);
|
||||
insert into z values(7);
|
||||
insert into z values(8);
|
||||
insert into z values(9);
|
||||
|
||||
##############################
|
||||
## section one cte定义
|
||||
## PART 1 定义表名的限制
|
||||
## PART 2 单个的定义
|
||||
## PART 3 多个定义
|
||||
## PART 4 subquery的变化
|
||||
## section two cte的使用
|
||||
## PART 0 cte结果正确性验证
|
||||
## PART 1 cte出现在normal型查询语句中
|
||||
## PART 2 cte出现在set型查询语句中
|
||||
## PART 3 关于数学的复杂case
|
||||
## section three cte能够出现的句式
|
||||
## PART 1 insert into
|
||||
## PART 2 select when
|
||||
## PART 3 delete from
|
||||
##############################
|
||||
|
||||
##############################
|
||||
## section one
|
||||
## PART 1 定义表名的限制
|
||||
##############################
|
||||
|
||||
## PART 1.1 表名,列名不能是保留关键字,可以是分保留关键字
|
||||
WITH explain(a) as (select 1 from dual union all select a+1 from explain where a+1 < 10) select * from explain;
|
||||
|
||||
WITH cte(explain) as (select 1 from dual union all select explain+1 from cte where explain+1 < 10) select * from cte;
|
||||
|
||||
## PART 1.2 允许与已有的表重名
|
||||
WITH t4(a) as (select 1 from dual union all select a+1 from t4 where a+1 < 10) select * from t4;
|
||||
|
||||
##############################
|
||||
## PART 2 单个的定义
|
||||
##############################
|
||||
|
||||
## PART 2.1 定义列名重复
|
||||
## 32049. 00000 - "duplicate name found in column alias list for WITH clause"
|
||||
with cte(a,a) as (select 1,1 from dual union all select a+1, a+1 from cte where a+1 < 10) select * from cte;
|
||||
|
||||
## PART 2.2.1 定义列数量与查询产生列一致或不一致
|
||||
with cte(a,b) as (select 1,1 from dual union all select a+1, a+1 from cte where a+1 < 10) select * from cte;
|
||||
|
||||
## 32038. 00000 - "number of WITH clause column names does not match number of elements in select list"
|
||||
with cte(a,b,c) as (select 1,1 from dual union all select a+1, a+1 from cte where a+1 < 10) select * from cte;
|
||||
|
||||
with cte(a) as (select 1,1 from dual union all select a+1, a+1 from cte where a+1 < 10) select * from cte;
|
||||
|
||||
## PART 2.2.2 不使用定义列使用原来的列
|
||||
with cte(a,b,c) as
|
||||
(
|
||||
select c1,c2,c3 from t1 where t1.c1 < 20
|
||||
union all
|
||||
select c1,c2,c3 from t1, cte where cte.a = t1.c1 and cte.c < 10
|
||||
) select c1,c2,c3 from cte;
|
||||
|
||||
|
||||
##############################
|
||||
## PART 3 多个的定义
|
||||
##############################
|
||||
|
||||
## 混合递归和非递归,前面的cte对后面的可见
|
||||
with cte as (select * from t1) ,
|
||||
cte_recursive (n) as (select 1 from dual union all select n+1 from cte_recursive where n < 23)
|
||||
select (select count(*) from cte_recursive) from t1;
|
||||
|
||||
with cte(n) as (select c1 from t1) ,
|
||||
cte_recursive (n) as (select 1 from dual union all select n+1 from cte where n < 23)
|
||||
select * from cte_recursive;
|
||||
|
||||
with cte(n) as (select c1 from t1) ,
|
||||
cte_recursive (n) as (select 1 from dual union all select n+1 from cte where n < 23)
|
||||
select (select count(*) from cte_recursive) from t1;
|
||||
|
||||
## PART 3.1 前面的定义引用后面的,后面的引用前面的
|
||||
WITH
|
||||
cte1 (a, b) AS (SELECT c, d FROM cte2),
|
||||
cte2 (c, d) AS (SELECT c21, c22 FROM t2)
|
||||
SELECT b, d FROM cte1 JOIN cte2
|
||||
on cte1.a = cte2.c;
|
||||
|
||||
|
||||
with
|
||||
cte1 AS (select c1 from t1),
|
||||
cte2 AS (select c1 from cte1)
|
||||
select * from cte1;
|
||||
|
||||
## PART 3.2.1 直接嵌套定义,MySQL支持这样的直接嵌套
|
||||
with
|
||||
cte1 AS (
|
||||
with cte2 AS (select c1 from t1)
|
||||
select c1 from cte2
|
||||
)
|
||||
select c1 from cte1;
|
||||
|
||||
with
|
||||
cte1 (cte1col) AS (
|
||||
with cte2 (cte2col) AS (select c1 from t1)
|
||||
select cte2col from cte2
|
||||
)
|
||||
select cte1col from cte1;
|
||||
|
||||
with
|
||||
cte1 (cte1col) AS (
|
||||
with cte2 (cte2col1, cte2col2) AS (select c1, c2 from t1)
|
||||
select cte2col2 from cte2
|
||||
)
|
||||
select cte1col from cte1;
|
||||
|
||||
## PART 3.2.2 在子查询中进行嵌套
|
||||
## 32034. 00000 - "unsupported use of WITH clause"
|
||||
with cte(a,b) as (select * from (with cteb(a, b) as (select c1, c2 from t1 union all select c+1, d+1 from cteb where c < 100) select * from cteb) bac) select * from cte;
|
||||
|
||||
with cteb(a,b) as
|
||||
(
|
||||
select c1, c2 from t1 union all select a+1, b+1 from cteb where a < 100
|
||||
),
|
||||
cte(c,d) as
|
||||
(
|
||||
select * from cteb bac
|
||||
)
|
||||
select * from cte;
|
||||
|
||||
## PART 3.2.3 测试能不能正确解析普通的union all
|
||||
with cte(a) as (select 1 from dual union all select 2 from dual), cte_1(b) as (select 1 from dual union all select * from cte) select * from cte_1;
|
||||
|
||||
##############################
|
||||
## PART 4 subquery的变化
|
||||
##############################
|
||||
|
||||
## PART 4.1.0 subquery的变化(限制)
|
||||
## 递归的句式主要变化在左支可以很负责,右支作join的的表可以是子查询,这个子查询可以写的
|
||||
## 非常的复杂
|
||||
## 递归cte只能有两个入口
|
||||
with cte(n) AS (select 1 from dual UNION ALL select n+1 from cte where n < 3 UNION ALL select 2 from dual) select * from cte;
|
||||
|
||||
## 递归必须包含union all
|
||||
with cte(n) AS ( select 1 from cte) select * from cte;
|
||||
|
||||
set @@ob_query_timeout=1000000;
|
||||
##32486. 00000 - "unsupported operation in recursive branch of recursive WITH clause "
|
||||
with cte(n) AS ( select 1 from dual UNION ALL select sum(n+1) from cte) select * from cte;
|
||||
|
||||
set @@ob_query_timeout=10000000;
|
||||
|
||||
##递归查询只允许有两个入口
|
||||
with cte(n) AS (select 1 from dual UNION ALL select n+1 from cte where n < 3 union all select n+1 from cte where n < 2) select * from cte;
|
||||
|
||||
with cte(n) as (select 1 from dual union all select c1 from t1 union all (with cte(n) as (select c1 from t1) select * from cte)) select * from cte;
|
||||
|
||||
with cte(n) as (select n from (select 1 from dual union all select n+1 from cte) tmp) select * from cte;
|
||||
|
||||
## 不能出现在right join的左边,left join的右边,full join的两边
|
||||
with cte(n) AS (select c1 from t1 UNION ALL select n+1 from cte right join t2 on cte.n < 3 and t2.c1 < 22) select * from cte;
|
||||
with cte(n) AS (select c1 from t1 UNION ALL select n+1 from t2 left join cte on cte.n < 3 and t2.c1 < 22) select * from cte;
|
||||
with cte(n) AS (select c1 from t1 UNION ALL select n+1 from t2 full join cte on cte.n < 3 and t2.c1 < 22) select * from cte;
|
||||
with cte(n) AS (select c1 from t1 UNION ALL select n+1 from cte full join t2 on cte.n < 3 and t2.c1 < 22) select * from cte;
|
||||
set @@ob_query_timeout=10000000;
|
||||
|
||||
|
||||
## PART 4.2 左支不停的变化
|
||||
## 带有where
|
||||
with
|
||||
cte2(c,d) AS (SELECT c1,c2 from t1 where c1 < 3 union all select c+1, d+1 from cte2 where c < 10)
|
||||
select c,d from cte2;
|
||||
|
||||
with
|
||||
cte2(c,d) AS (SELECT c1,c2 from t1 where c1+'1' <= 3 union all select c+1, d+1 from cte2 where c < 10)
|
||||
select c,d from cte2;
|
||||
|
||||
## 带有group
|
||||
with
|
||||
cte2(c,d) AS (SELECT c1,c2 from t1 group by c1,c2 union all select c+1, d+1 from cte2 where c < 10)
|
||||
select c,d from cte2;
|
||||
|
||||
## 带有having
|
||||
with
|
||||
cte2(c,d) AS (SELECT c1,c2 from t1 where t1.c1 > 5 union all select c+1, d+1 from cte2 where c < 30)
|
||||
select c,d from cte2;
|
||||
|
||||
## 带有order
|
||||
with
|
||||
cte2(c,d) AS ( select c1, c2 + 1 as c3 from t1 order by c2 union all select c+1, d+1 from cte2 where c < 30)
|
||||
select c,d from cte2;
|
||||
|
||||
with
|
||||
cte2(c,d) AS (select t1.c1, t2.c2 from t1 left join t2 on t1.c1=t2.c1 order by t1.c1 union all select c+1, d+1 from cte2 where c < 30)
|
||||
select c from cte2;
|
||||
|
||||
|
||||
## PART 4.3 右支不停的变化
|
||||
with
|
||||
cte(c,d) AS (SELECT c1,c2 from t1 where c1 < 3 union all select c+1, d+1 from cte, t2 where t2.c1 = c and t2.c2 > some (select c1 from t44 t99 group by c1))
|
||||
select * from cte;
|
||||
|
||||
with
|
||||
cte(c,d) AS (SELECT c1,c2 from t1 where c1 < 3 union all select c+1, d+1 from cte, t2 where t2.c1 = c and t2.c2 > some (select c1 from t44 t99 group by c1))
|
||||
select * from cte;
|
||||
|
||||
#递归cte中间表与已有的表重名
|
||||
create table ex (c1 int, c2 int);
|
||||
|
||||
with ex(c1, c2) as (select 1, 1 from dual union all select c1+1, c2+1 from ex where c1 < 5) select * from ex;
|
||||
|
||||
with ex(c1, c2) as (select 1, 1 from dual union all select c1+1, c2+1 from ex where c1 < 5) select * from ex;
|
||||
|
||||
|
||||
##############################
|
||||
## section two cte的使用
|
||||
##############################
|
||||
|
||||
## PART 0 cte结果正确性验证
|
||||
## 基础case
|
||||
with cte(n) as (select 1 from dual union all select n+1 from cte where n < 23) select n from cte;
|
||||
|
||||
with cte (a,b,c) as ( select id, name, leaderid from emp where emp.id = 1 union all select emp.id ,emp.name, emp.leaderid from emp, cte where emp.leaderid = cte.a ) select * from cte;
|
||||
|
||||
|
||||
## 与MySQL结果进行核对,验证正确性,句式1
|
||||
|
||||
with cte( id, val, lev) as (
|
||||
select id, value , 0 as lev from t4 where parent_id is null
|
||||
union all
|
||||
select t4.id, t4.value, cte.lev+1 from cte join t4 on t4.parent_id=cte.id)
|
||||
select * from cte;
|
||||
|
||||
## 与MySQL结果进行核对,验证正确性,句式3
|
||||
|
||||
with cte(a,b,c) as
|
||||
(
|
||||
select c1,c2,c3 from t1 where t1.c1 < 20
|
||||
union all
|
||||
select c1,c2,c3 from t1, cte where cte.a = t1.c1 and cte.c < 10
|
||||
) select * from cte;
|
||||
|
||||
## 与MySQL结果进行核对,验证正确性,句式4
|
||||
with cte (a,b,c) as
|
||||
(
|
||||
select id, name, leaderid from emp where emp.id = 1
|
||||
union all
|
||||
select emp.id ,emp.name, emp.leaderid from emp, cte where emp.leaderid = cte.a
|
||||
)
|
||||
select * from cte;
|
||||
|
||||
## join hint
|
||||
with cte(n) as
|
||||
(
|
||||
select /*+NO_USE_HASH(t1,t2)*/ t1.c1 from t1, t2 where t1.c1 = t2.c1
|
||||
union all
|
||||
select t1.c1 from cte, t1 where t1.c1 = cte.n
|
||||
)
|
||||
select * from cte;
|
||||
|
||||
|
||||
## 结果正确
|
||||
with cte(a,b,c) as
|
||||
(
|
||||
select c1,c2,c3 from t1 where t1.c1 < 20
|
||||
union all
|
||||
select c1,c2,c3 from t1, cte where cte.a = t1.c1 and cte.c < 10)
|
||||
select count(distinct cte.a), avg(distinct cte.b) from cte where cte.c < 10;
|
||||
|
||||
|
||||
|
||||
## PART 1 cte出现在normal型查询语句中
|
||||
## PART 1.1 最基本用法(单表)
|
||||
## 最简单的使用方法
|
||||
|
||||
with cte as (select * from t1) select (
|
||||
with cte(col1, col2, col3) as(select * from t2) select count(*) from cte
|
||||
) from t1;
|
||||
with cte(col1, col2, col3) as(select * from t2) select count(*) from cte
|
||||
) |
|
||||
|
||||
|
||||
with cte(a,b,c) as
|
||||
(
|
||||
select c1,c2,c3 from t1 where t1.c1 < 20
|
||||
union all
|
||||
select c1,c2,c3 from t1, cte where cte.a = t1.c1 and cte.c < 10
|
||||
)
|
||||
select a, b, c from cte;
|
||||
|
||||
## 主句含有order + 对伪列排序序
|
||||
with cte(a,b,c) as
|
||||
(
|
||||
select c1,c2,c3 from t1 where t1.c1 < 20
|
||||
union all
|
||||
select c1,c2,c3 from t1, cte where cte.a = t1.c1 and cte.c < 10
|
||||
)
|
||||
select a, b, c from cte order by a;
|
||||
|
||||
## 对主句中的cte取别名后看看能否继续使用+在in中使用+where
|
||||
with cte(a,b,c) as
|
||||
(
|
||||
select c1,c2,c3 from t1 where t1.c1 < 20
|
||||
union all
|
||||
select c1,c2,c3 from t1, cte where cte.a = t1.c1 and cte.c < 10
|
||||
)
|
||||
select z1.a from cte z1, t2 where z1.a in (1,4,7,11) and z1.a = t2.c2;
|
||||
|
||||
## 重命名的列出现在order+where中
|
||||
with cte(a,b,c) as
|
||||
(
|
||||
select c1,c2,c3 from t1 where t1.c1 < 20
|
||||
union all
|
||||
select c1,c2,c3 from t1, cte where cte.a = t1.c1 and cte.c < 10
|
||||
)
|
||||
select a from cte where a in (1,4,11) order by a;
|
||||
|
||||
## 别名列和原本列的名字一样
|
||||
with cte(c1,c2,c3) as
|
||||
(
|
||||
select c1,c2,c3 from t1 where t1.c1 < 20
|
||||
union all
|
||||
select c1,c2,c3 from t1, cte where cte.c1 = t1.c1 and cte.c3 < 10
|
||||
)
|
||||
select c2 from cte;
|
||||
|
||||
## 在field list中写了inline,里面使用了cte
|
||||
with cte(n) as (select 1 from dual union all select n+1 from cte where n < 23) select (select count(*) from cte) from cte;
|
||||
|
||||
## join+having not+order by
|
||||
with cte1(a,b,c) as
|
||||
(
|
||||
select c1,c2,c3 from t1 where t1.c1 < 20
|
||||
union all
|
||||
select c1,c2,c3 from t1, cte1 cte where cte.a = t1.c1 and cte.c < 10
|
||||
)
|
||||
select * from cte1 left join t2 on cte1.a=t2.c1 where t2.c1 != cte1.a order by cte1.a;
|
||||
|
||||
|
||||
|
||||
## PART 1.2 最基本用法(多表)
|
||||
|
||||
## 第三cte引用第二个,第二个又引用第一个。结果与MySQL一致。
|
||||
explain basic
|
||||
with cte1(a,b,c) as
|
||||
(
|
||||
select 1,1,1 from dual
|
||||
union all
|
||||
select a+1,b+1,c+1 from cte1 where cte1.a < 10
|
||||
),
|
||||
cte2 (a,b,c) as
|
||||
(
|
||||
select cte1.a,cte1.b,cte1.c from cte1
|
||||
union all
|
||||
select a+1,b+1,c+1 from cte2 where cte2.a < 10
|
||||
),
|
||||
cte3 (a,b,c) as
|
||||
(
|
||||
select cte2.a,cte2.b,cte2.c from cte2
|
||||
union all
|
||||
select cte3.a+1,cte3.b+1,cte3.c+1 from cte3, cte2 where cte2.a < 3 and cte3.a < cte2.b and cte3.a < 10
|
||||
)
|
||||
SELECT cte1.a, cte1.b FROM cte1 JOIN cte3
|
||||
on cte1.a < cte3.c;
|
||||
|
||||
set ob_query_timeout = 100000000;
|
||||
with cte1(a,b,c) as
|
||||
(
|
||||
select 1,1,1 from dual
|
||||
union all
|
||||
select a+1,b+1,c+1 from cte1 where cte1.a < 10
|
||||
),
|
||||
cte2 (a,b,c) as
|
||||
(
|
||||
select cte1.a,cte1.b,cte1.c from cte1
|
||||
union all
|
||||
select a+1,b+1,c+1 from cte2 where cte2.a < 10
|
||||
),
|
||||
cte3 (a,b,c) as
|
||||
(
|
||||
select cte2.a,cte2.b,cte2.c from cte2
|
||||
union all
|
||||
select cte3.a+1,cte3.b+1,cte3.c+1 from cte3, cte2 where cte2.a < 3 and cte3.a < cte2.b and cte3.a < 10
|
||||
)
|
||||
SELECT cte1.a, cte1.b FROM cte1 JOIN cte3
|
||||
on cte1.a < cte3.c;
|
||||
set ob_query_timeout = 10000000;
|
||||
|
||||
|
||||
## 关于数学的复杂case
|
||||
##about math
|
||||
WITH fibonacci (n, fib_n, next_fib_n) AS
|
||||
(
|
||||
SELECT 1, 0, 1 from dual
|
||||
UNION ALL
|
||||
SELECT n + 1, next_fib_n, fib_n + next_fib_n
|
||||
FROM fibonacci WHERE n < 10
|
||||
)
|
||||
SELECT * FROM fibonacci;
|
||||
|
||||
with cte(n) as (select 1 from dual union all select n+1 from cte where n<6),
|
||||
prod(lastnum, lastprod) as (select min(n), min(n) from cte
|
||||
union all
|
||||
select n, n*lastprod from cte, prod where n = prod.lastnum+1)
|
||||
select * from prod;
|
||||
|
||||
with cte as (select 18 d from dual),
|
||||
prod (lastnum, lastprod) as (
|
||||
select 1, 1 from dual
|
||||
union all
|
||||
select lastnum+1, (lastnum+1)*lastprod from prod, cte where lastnum < d)
|
||||
select * from prod, cte where lastnum = d;
|
||||
|
||||
|
||||
|
||||
##############################
|
||||
## insert into
|
||||
##############################
|
||||
insert into insert_t with cte(a,b,c) as (select 1,2,3 from dual union all select a+1,b+1,c+1 from cte where a < 10) SELECT * FROM cte;
|
||||
select * from insert_t;
|
||||
|
||||
|
||||
##############################
|
||||
## select when
|
||||
##############################
|
||||
with cte(c1, c2, c3) as (select 1,1,1 from dual union all select c1+1,c2+1,c3+1 from cte where cte.c1 < 50) select c1, max(c2), CASE max(c2) when 4 then 4 when 43 then 43 else 1 end from cte group by c1 order by c1;
|
||||
|
||||
##############################
|
||||
## delete from
|
||||
##############################
|
||||
|
||||
delete from t1 where c1 = ( with cte(c1, c2, c3) as (select 1,1,1 from dual union all select c1+1,c2+1,c3+1 from cte where cte.c1 < 50) select c1 from cte where c2 = 3);
|
||||
select * from t1;
|
||||
|
@ -0,0 +1,67 @@
|
||||
drop database if exists ctetest;
|
||||
create database ctetest;
|
||||
use ctetest;
|
||||
create table EMP (
|
||||
EMPno number,
|
||||
ENAME varchar(30),
|
||||
JOB varchar(30),
|
||||
MGR number(4),
|
||||
HIREDATE date,
|
||||
SAL number(7,2),
|
||||
COMM number(7,2),
|
||||
DEPTNO number(2)
|
||||
) ;
|
||||
create table DEPT(
|
||||
DEPTNO number(2),
|
||||
DNAME char(45),
|
||||
LOC varchar(39)
|
||||
) ;
|
||||
insert into EMP values (7369,'SMITH','CLERK',7902, str_to_date('17-DEC-80','%d-%b-%Y'),800,NULL, 20) ;
|
||||
INSERT INTO EMP VALUES (7499, 'ALLEN','SALESMAN',7698,str_to_date('20-FEB-81','%d-%b-%Y'),1600,300,30) ;
|
||||
INSERT INTO EMP VALUES (7521,'WARD','SALESMAN',7698, str_to_date('22-FEB-81','%d-%b-%Y'),1250, 500, 30) ;
|
||||
INSERT INTO EMP VALUES (7566,'JONES','MANAGER',7839, str_to_date('02-APR-81','%d-%b-%Y'), 2975, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES (7654,'MARTIN','SALESMAN', 7698, str_to_date('28-SEP-81','%d-%b-%Y'), 1250, 1400, 30) ;
|
||||
INSERT INTO EMP VALUES (7698, 'BLAKE','MANAGER', 7839, str_to_date('01-MAY-81','%d-%b-%Y'), 2850, NULL, 30) ;
|
||||
INSERT INTO EMP VALUES (7782, 'CLARK','MANAGER', 7839, str_to_date('09-JUN-81','%d-%b-%Y'), 2450, NULL, 10) ;
|
||||
insert into EMP values (7788,'SCOTT','ANALYST', 7566, str_to_date('19-APR-87','%d-%b-%Y'), 3000, null, 20) ;
|
||||
INSERT INTO EMP VALUES (7839, 'KING','PRESIDENT', NULL, str_to_date('17-NOV-81','%d-%b-%Y'), 5000, NULL, 10) ;
|
||||
INSERT INTO EMP VALUES (7844, 'TURNER','SALESMAN', 7698, str_to_date('08-SEP-81','%d-%b-%Y'), 1500, 0, 30) ;
|
||||
INSERT INTO EMP VALUES(7876, 'ADAMS','CLERK', 7788, str_to_date('23-MAY-87','%d-%b-%Y'), 1100, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES(7900, 'JAMES', 'CLEARK', 7698, str_to_date('03-DEC-81','%d-%b-%Y'), 950, NULL, 30) ;
|
||||
INSERT INTO EMP VALUES(7902, 'FORD','ANALYST',7566, str_to_date('03-DEC-81','%d-%b-%Y'), 3000, NULL, 20) ;
|
||||
INSERT INTO EMP VALUES(7934,'MILLER','CLERK', 7782, str_to_date('23-JAN-82','%d-%b-%Y'), 1300,NULL, 10) ;
|
||||
result_format: 4
|
||||
|
||||
## =======================================================================
|
||||
## Test Case 1:
|
||||
## - recursive WITH Query: Optimization on query with outside filter.
|
||||
## Predicate pushdown optimization on static value job.
|
||||
## The plan should reflect optimization or development can provide
|
||||
## parameter to show that pushdown optimization happened for init branch
|
||||
## =======================================================================
|
||||
explain basic
|
||||
WITH rw (ename, mgr, empno, job) AS
|
||||
(
|
||||
SELECT ename, mgr, empno, job
|
||||
FROM emp e
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno, e.job
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT ename, empno, mgr, job
|
||||
FROM rw
|
||||
WHERE job = 'PRESIDENT' ;
|
||||
|
||||
WITH rw (ename, mgr, empno, job) AS
|
||||
(
|
||||
SELECT ename, mgr, empno, job
|
||||
FROM emp e
|
||||
UNION ALL
|
||||
SELECT e.ename, e.mgr, e.empno, e.job
|
||||
FROM rw r, emp e
|
||||
WHERE r.empno = e.mgr
|
||||
)
|
||||
SELECT /*+ :HINT: */ ename, empno, mgr, job
|
||||
FROM rw
|
||||
WHERE job = 'PRESIDENT' ;
|
Loading…
x
Reference in New Issue
Block a user