Fix start with connect by.
This commit is contained in:
@ -159,6 +159,7 @@ static void CreateStartWithCTE(ParseState *pstate,
|
||||
|
||||
static Node *makeBoolAConst(bool state, int location);
|
||||
static StartWithRewrite ChooseSWCBStrategy(StartWithTransformContext context);
|
||||
static Node *tryReplaceFakeValue(Node *node);
|
||||
|
||||
static Node *makeBoolAConst(bool state, int location)
|
||||
{
|
||||
@ -754,17 +755,38 @@ static Node* makeIntConst(int val, int location)
|
||||
return (Node *)n;
|
||||
}
|
||||
|
||||
static Node* tryReplaceFakeValue(Node *node)
|
||||
static Node *replaceListFakeValue(List *lst)
|
||||
{
|
||||
List *newArgs = NIL;
|
||||
ListCell *lc = NULL;
|
||||
bool replaced = false;
|
||||
|
||||
/* replace level/rownum var attr with fake consts */
|
||||
foreach (lc, lst) {
|
||||
Node *n = (Node *)lfirst(lc);
|
||||
Node *newNode = tryReplaceFakeValue(n);
|
||||
if (newNode != n) {
|
||||
replaced = true;
|
||||
n = newNode;
|
||||
}
|
||||
newArgs = lappend(newArgs, n);
|
||||
}
|
||||
return replaced ? (Node *)newArgs : (Node *)lst;
|
||||
}
|
||||
|
||||
static Node *tryReplaceFakeValue(Node *node)
|
||||
{
|
||||
if (IsA(node, Rownum)) {
|
||||
node = makeIntConst(CONNECT_BY_ROWNUM_FAKEVALUE, -1);
|
||||
} else if (is_cref_by_name(node, "level")) {
|
||||
node = makeIntConst(CONNECT_BY_LEVEL_FAKEVALUE, -1);
|
||||
} else if (IsA(node, List)) {
|
||||
node = replaceListFakeValue((List *) node);
|
||||
}
|
||||
return node;
|
||||
}
|
||||
|
||||
static bool pseudo_level_rownum_walker(Node *node, Node* context_parent_node)
|
||||
static bool pseudo_level_rownum_walker(Node *node, Node *context_parent_node)
|
||||
{
|
||||
if (node == NULL) {
|
||||
return false;
|
||||
@ -789,15 +811,20 @@ static bool pseudo_level_rownum_walker(Node *node, Node* context_parent_node)
|
||||
break;
|
||||
}
|
||||
case T_TypeCast: {
|
||||
TypeCast* tc = (TypeCast*) context_parent_node;
|
||||
TypeCast *tc = (TypeCast *) context_parent_node;
|
||||
tc->arg = newNode;
|
||||
break;
|
||||
}
|
||||
case T_NullTest: {
|
||||
NullTest* nt = (NullTest*) context_parent_node;
|
||||
NullTest *nt = (NullTest *) context_parent_node;
|
||||
nt->arg = (Expr*) newNode;
|
||||
break;
|
||||
}
|
||||
case T_FuncCall: {
|
||||
FuncCall *fc = (FuncCall *) context_parent_node;
|
||||
fc->args = (List *)newNode;
|
||||
break;
|
||||
}
|
||||
default:
|
||||
break;
|
||||
}
|
||||
@ -1288,7 +1315,8 @@ static SelectStmt *CreateStartWithCTEInnerBranch(ParseState* pstate,
|
||||
|
||||
if (whereClause != NULL) {
|
||||
JoinExpr *final_join = (JoinExpr *)origin_table;
|
||||
final_join->quals = whereClause;
|
||||
/* pushdown requires deep copying of the quals */
|
||||
final_join->quals = (Node *)copyObject(whereClause);
|
||||
}
|
||||
}
|
||||
|
||||
@ -1387,10 +1415,14 @@ static SelectStmt *CreateStartWithCTEOuterBranch(ParseState *pstate,
|
||||
}
|
||||
}
|
||||
|
||||
if (whereClause == NULL) {
|
||||
quals = (Node *)startWithExpr;
|
||||
} else {
|
||||
quals = (Node *)makeA_Expr(AEXPR_AND, NULL, whereClause, (Node*)startWithExpr, -1);
|
||||
/* push whereClause down to init part, taking care to avoid NULL in expr. */
|
||||
quals = (Node *)startWithExpr;
|
||||
if (quals == NULL) {
|
||||
/* pushdown requires deep copying of the quals */
|
||||
quals = (Node *)copyObject(whereClause);
|
||||
} else if (whereClause != NULL) {
|
||||
quals = (Node *)makeA_Expr(AEXPR_AND, NULL, (Node *)copyObject(whereClause),
|
||||
(Node*)startWithExpr, -1);
|
||||
}
|
||||
|
||||
result->fromClause = tblist;
|
||||
|
||||
630
src/test/regress/expected/sw_basic.out
Normal file
630
src/test/regress/expected/sw_basic.out
Normal file
@ -0,0 +1,630 @@
|
||||
set client_min_messages = error;
|
||||
set search_path=swtest;
|
||||
SET CLIENT_ENCODING='UTF8';
|
||||
/*
|
||||
*
|
||||
* START WITH .... CONNECT BY基础测试用例
|
||||
*
|
||||
* 测试用例表数
|
||||
* openGauss=# select * from swtest.test_area;
|
||||
* id | name | fatherid | name_desc
|
||||
* ----+--------+----------+-----------
|
||||
* 1 | 中国 | 0 | china
|
||||
* 2 | 湖南省 | 1 | hunan
|
||||
* 3 | 广东省 | 1 | guangdong
|
||||
* 4 | 海南省 | 1 | hainan
|
||||
* 5 | 河北省 | 1 | hebei
|
||||
* 6 | 河南省 | 1 | henan
|
||||
* 7 | 山东省 | 1 | shandong
|
||||
* 8 | 湖北省 | 1 | hubei
|
||||
* 9 | 江苏省 | 1 | jiangsu
|
||||
* 10 | 深圳市 | 3 | shenzhen
|
||||
* 11 | 长沙市 | 2 | changsha
|
||||
* 22 | 祁北县 | 13 | qibei
|
||||
* 12 | 南山区 | 10 | nanshan
|
||||
* 21 | 祁西县 | 13 | qixi
|
||||
* 13 | 衡阳市 | 2 | hengyang
|
||||
* 14 | 耒阳市 | 13 | leiyang
|
||||
* 15 | 龙岗区 | 10 | longgang
|
||||
* 16 | 福田区 | 10 | futian
|
||||
* 17 | 宝安区 | 10 | baoan
|
||||
* 19 | 祁东县 | 13 | qidong
|
||||
* 18 | 常宁市 | 13 | changning
|
||||
* 20 | 祁南县 | 13 | qinan
|
||||
*
|
||||
*/
|
||||
-- 一、基础语法测试
|
||||
/*
|
||||
* 用例1.1,基础用例包含所有伪列,leaf节点方向遍历查找
|
||||
**/
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '@')
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1, array_col_4
|
||||
-> Recursive Union
|
||||
-> Seq Scan on test_area
|
||||
Filter: (name = '中国'::text)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.fatherid = tmp_reuslt."test_area@id")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(12 rows)
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '@')
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
id | name | fatherid | name_desc | level | connect_by_isleaf | connect_by_iscycle | connect_by_root | sys_connect_by_path
|
||||
----+--------+----------+-----------+-------+-------------------+--------------------+-----------------+------------------------------------
|
||||
1 | 中国 | 0 | China | 1 | 0 | 0 | China | @China
|
||||
2 | 湖南省 | 1 | Hunan | 2 | 0 | 0 | China | @China@Hunan
|
||||
3 | 广东省 | 1 | Guangdong | 2 | 0 | 0 | China | @China@Guangdong
|
||||
4 | 海南省 | 1 | Hainan | 2 | 1 | 0 | China | @China@Hainan
|
||||
5 | 河北省 | 1 | Hebei | 2 | 1 | 0 | China | @China@Hebei
|
||||
6 | 河南省 | 1 | Henan | 2 | 1 | 0 | China | @China@Henan
|
||||
7 | 山东省 | 1 | Shandong | 2 | 1 | 0 | China | @China@Shandong
|
||||
8 | 湖北省 | 1 | Hubei | 2 | 1 | 0 | China | @China@Hubei
|
||||
9 | 江苏省 | 1 | Jiangsu | 2 | 1 | 0 | China | @China@Jiangsu
|
||||
10 | 深圳市 | 3 | Shenzhen | 3 | 0 | 0 | China | @China@Guangdong@Shenzhen
|
||||
11 | 长沙市 | 2 | Changsha | 3 | 1 | 0 | China | @China@Hunan@Changsha
|
||||
13 | 衡阳市 | 2 | Hengyang | 3 | 0 | 0 | China | @China@Hunan@Hengyang
|
||||
22 | 祁北县 | 13 | Qibei | 4 | 1 | 0 | China | @China@Hunan@Hengyang@Qibei
|
||||
12 | 南山区 | 10 | Nanshan | 4 | 1 | 0 | China | @China@Guangdong@Shenzhen@Nanshan
|
||||
21 | 祁西县 | 13 | Qixi | 4 | 1 | 0 | China | @China@Hunan@Hengyang@Qixi
|
||||
14 | 耒阳市 | 13 | Leiyang | 4 | 1 | 0 | China | @China@Hunan@Hengyang@Leiyang
|
||||
15 | 龙岗区 | 10 | Longgang | 4 | 1 | 0 | China | @China@Guangdong@Shenzhen@Longgang
|
||||
16 | 福田区 | 10 | Futian | 4 | 1 | 0 | China | @China@Guangdong@Shenzhen@Futian
|
||||
17 | 宝安区 | 10 | Baoan | 4 | 1 | 0 | China | @China@Guangdong@Shenzhen@Baoan
|
||||
19 | 祁东县 | 13 | Qidong | 4 | 1 | 0 | China | @China@Hunan@Hengyang@Qidong
|
||||
18 | 常宁市 | 13 | Changning | 4 | 1 | 0 | China | @China@Hunan@Hengyang@Changning
|
||||
20 | 祁南县 | 13 | Qinan | 4 | 1 | 0 | China | @China@Hunan@Hengyang@Qinan
|
||||
(22 rows)
|
||||
|
||||
/*
|
||||
* 用例1.2,基础用例包含所有伪列,root节点方向遍历查找
|
||||
**/
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '@')
|
||||
FROM test_area
|
||||
START WITH name = '耒阳市'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_3, array_col_4
|
||||
-> Recursive Union
|
||||
-> Seq Scan on test_area
|
||||
Filter: (name = '耒阳市'::text)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.id = tmp_reuslt."test_area@fatherid")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(12 rows)
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '@')
|
||||
FROM test_area
|
||||
START WITH name = '耒阳市'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
id | name | fatherid | name_desc | level | connect_by_isleaf | connect_by_iscycle | connect_by_root | sys_connect_by_path
|
||||
----+--------+----------+-----------+-------+-------------------+--------------------+-----------------+-------------------------------
|
||||
14 | 耒阳市 | 13 | Leiyang | 1 | 0 | 0 | Leiyang | @Leiyang
|
||||
13 | 衡阳市 | 2 | Hengyang | 2 | 0 | 0 | Leiyang | @Leiyang@Hengyang
|
||||
2 | 湖南省 | 1 | Hunan | 3 | 0 | 0 | Leiyang | @Leiyang@Hengyang@Hunan
|
||||
1 | 中国 | 0 | China | 4 | 1 | 0 | Leiyang | @Leiyang@Hengyang@Hunan@China
|
||||
(4 rows)
|
||||
|
||||
/*
|
||||
* 用例1.3,基础用例包含所有伪列,root节点方向遍历查找(两条链)
|
||||
**/
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '@')
|
||||
FROM test_area
|
||||
START WITH name = '耒阳市' OR name = '宝安区'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_3, array_col_4
|
||||
-> Recursive Union
|
||||
-> Seq Scan on test_area
|
||||
Filter: ((name = '耒阳市'::text) OR (name = '宝安区'::text))
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.id = tmp_reuslt."test_area@fatherid")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(12 rows)
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '@')
|
||||
FROM test_area
|
||||
START WITH name = '耒阳市' OR name = '宝安区'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
id | name | fatherid | name_desc | level | connect_by_isleaf | connect_by_iscycle | connect_by_root | sys_connect_by_path
|
||||
----+--------+----------+-----------+-------+-------------------+--------------------+-----------------+---------------------------------
|
||||
14 | 耒阳市 | 13 | Leiyang | 1 | 0 | 0 | Leiyang | @Leiyang
|
||||
17 | 宝安区 | 10 | Baoan | 1 | 0 | 0 | Baoan | @Baoan
|
||||
10 | 深圳市 | 3 | Shenzhen | 2 | 0 | 0 | Baoan | @Baoan@Shenzhen
|
||||
13 | 衡阳市 | 2 | Hengyang | 2 | 0 | 0 | Leiyang | @Leiyang@Hengyang
|
||||
2 | 湖南省 | 1 | Hunan | 3 | 0 | 0 | Leiyang | @Leiyang@Hengyang@Hunan
|
||||
3 | 广东省 | 1 | Guangdong | 3 | 0 | 0 | Baoan | @Baoan@Shenzhen@Guangdong
|
||||
1 | 中国 | 0 | China | 4 | 1 | 0 | Baoan | @Baoan@Shenzhen@Guangdong@China
|
||||
1 | 中国 | 0 | China | 4 | 1 | 0 | Leiyang | @Leiyang@Hengyang@Hunan@China
|
||||
(8 rows)
|
||||
|
||||
/*
|
||||
* 用例1.5,基础用例包含所有伪列,测试多字符串拼接
|
||||
**/
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '=>>')
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1, array_col_4
|
||||
-> Recursive Union
|
||||
-> Seq Scan on test_area
|
||||
Filter: (name = '中国'::text)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.fatherid = tmp_reuslt."test_area@id")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(12 rows)
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '=>>')
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
id | name | fatherid | name_desc | level | connect_by_isleaf | connect_by_iscycle | connect_by_root | sys_connect_by_path
|
||||
----+--------+----------+-----------+-------+-------------------+--------------------+-----------------+--------------------------------------------
|
||||
1 | 中国 | 0 | China | 1 | 0 | 0 | China | =>>China
|
||||
2 | 湖南省 | 1 | Hunan | 2 | 0 | 0 | China | =>>China=>>Hunan
|
||||
3 | 广东省 | 1 | Guangdong | 2 | 0 | 0 | China | =>>China=>>Guangdong
|
||||
4 | 海南省 | 1 | Hainan | 2 | 1 | 0 | China | =>>China=>>Hainan
|
||||
5 | 河北省 | 1 | Hebei | 2 | 1 | 0 | China | =>>China=>>Hebei
|
||||
6 | 河南省 | 1 | Henan | 2 | 1 | 0 | China | =>>China=>>Henan
|
||||
7 | 山东省 | 1 | Shandong | 2 | 1 | 0 | China | =>>China=>>Shandong
|
||||
8 | 湖北省 | 1 | Hubei | 2 | 1 | 0 | China | =>>China=>>Hubei
|
||||
9 | 江苏省 | 1 | Jiangsu | 2 | 1 | 0 | China | =>>China=>>Jiangsu
|
||||
10 | 深圳市 | 3 | Shenzhen | 3 | 0 | 0 | China | =>>China=>>Guangdong=>>Shenzhen
|
||||
11 | 长沙市 | 2 | Changsha | 3 | 1 | 0 | China | =>>China=>>Hunan=>>Changsha
|
||||
13 | 衡阳市 | 2 | Hengyang | 3 | 0 | 0 | China | =>>China=>>Hunan=>>Hengyang
|
||||
22 | 祁北县 | 13 | Qibei | 4 | 1 | 0 | China | =>>China=>>Hunan=>>Hengyang=>>Qibei
|
||||
12 | 南山区 | 10 | Nanshan | 4 | 1 | 0 | China | =>>China=>>Guangdong=>>Shenzhen=>>Nanshan
|
||||
21 | 祁西县 | 13 | Qixi | 4 | 1 | 0 | China | =>>China=>>Hunan=>>Hengyang=>>Qixi
|
||||
14 | 耒阳市 | 13 | Leiyang | 4 | 1 | 0 | China | =>>China=>>Hunan=>>Hengyang=>>Leiyang
|
||||
15 | 龙岗区 | 10 | Longgang | 4 | 1 | 0 | China | =>>China=>>Guangdong=>>Shenzhen=>>Longgang
|
||||
16 | 福田区 | 10 | Futian | 4 | 1 | 0 | China | =>>China=>>Guangdong=>>Shenzhen=>>Futian
|
||||
17 | 宝安区 | 10 | Baoan | 4 | 1 | 0 | China | =>>China=>>Guangdong=>>Shenzhen=>>Baoan
|
||||
19 | 祁东县 | 13 | Qidong | 4 | 1 | 0 | China | =>>China=>>Hunan=>>Hengyang=>>Qidong
|
||||
18 | 常宁市 | 13 | Changning | 4 | 1 | 0 | China | =>>China=>>Hunan=>>Hengyang=>>Changning
|
||||
20 | 祁南县 | 13 | Qinan | 4 | 1 | 0 | China | =>>China=>>Hunan=>>Hengyang=>>Qinan
|
||||
(22 rows)
|
||||
|
||||
/*
|
||||
* 用例1.6,基础用例包含所有伪列, 包含多字符拼接,多条查找链,startwith使用LIKE查找
|
||||
**/
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '-*>')
|
||||
FROM test_area
|
||||
START WITH name like '%区'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_3, array_col_4
|
||||
-> Recursive Union
|
||||
-> Seq Scan on test_area
|
||||
Filter: (name ~~ '%区'::text)
|
||||
-> Hash Join
|
||||
Hash Cond: (tmp_reuslt."test_area@fatherid" = swtest.test_area.id)
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> Hash
|
||||
-> Seq Scan on test_area
|
||||
(12 rows)
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '-*>')
|
||||
FROM test_area
|
||||
START WITH name like '%区'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
id | name | fatherid | name_desc | level | connect_by_isleaf | connect_by_iscycle | connect_by_root | sys_connect_by_path
|
||||
----+--------+----------+-----------+-------+-------------------+--------------------+-----------------+--------------------------------------------
|
||||
12 | 南山区 | 10 | Nanshan | 1 | 0 | 0 | Nanshan | -*>Nanshan
|
||||
15 | 龙岗区 | 10 | Longgang | 1 | 0 | 0 | Longgang | -*>Longgang
|
||||
16 | 福田区 | 10 | Futian | 1 | 0 | 0 | Futian | -*>Futian
|
||||
17 | 宝安区 | 10 | Baoan | 1 | 0 | 0 | Baoan | -*>Baoan
|
||||
10 | 深圳市 | 3 | Shenzhen | 2 | 0 | 0 | Nanshan | -*>Nanshan-*>Shenzhen
|
||||
10 | 深圳市 | 3 | Shenzhen | 2 | 0 | 0 | Longgang | -*>Longgang-*>Shenzhen
|
||||
10 | 深圳市 | 3 | Shenzhen | 2 | 0 | 0 | Futian | -*>Futian-*>Shenzhen
|
||||
10 | 深圳市 | 3 | Shenzhen | 2 | 0 | 0 | Baoan | -*>Baoan-*>Shenzhen
|
||||
3 | 广东省 | 1 | Guangdong | 3 | 0 | 0 | Nanshan | -*>Nanshan-*>Shenzhen-*>Guangdong
|
||||
3 | 广东省 | 1 | Guangdong | 3 | 0 | 0 | Longgang | -*>Longgang-*>Shenzhen-*>Guangdong
|
||||
3 | 广东省 | 1 | Guangdong | 3 | 0 | 0 | Futian | -*>Futian-*>Shenzhen-*>Guangdong
|
||||
3 | 广东省 | 1 | Guangdong | 3 | 0 | 0 | Baoan | -*>Baoan-*>Shenzhen-*>Guangdong
|
||||
1 | 中国 | 0 | China | 4 | 1 | 0 | Nanshan | -*>Nanshan-*>Shenzhen-*>Guangdong-*>China
|
||||
1 | 中国 | 0 | China | 4 | 1 | 0 | Longgang | -*>Longgang-*>Shenzhen-*>Guangdong-*>China
|
||||
1 | 中国 | 0 | China | 4 | 1 | 0 | Futian | -*>Futian-*>Shenzhen-*>Guangdong-*>China
|
||||
1 | 中国 | 0 | China | 4 | 1 | 0 | Baoan | -*>Baoan-*>Shenzhen-*>Guangdong-*>China
|
||||
(16 rows)
|
||||
|
||||
-- 二、扩展测试
|
||||
/*
|
||||
* 用例2.1,基础用例包含所有伪列, 包含多字符拼接,多条查找链,startwith使用IN子查询进行查找
|
||||
**/
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '/')
|
||||
FROM test_area
|
||||
START WITH name IN (select name from test_area where id < 3)
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1, array_col_4
|
||||
-> Recursive Union
|
||||
-> Hash Semi Join
|
||||
Hash Cond: (swtest.test_area.name = swtest.test_area.name)
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> Seq Scan on test_area
|
||||
Filter: (id < 3)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.fatherid = tmp_reuslt."test_area@id")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(16 rows)
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '/')
|
||||
FROM test_area
|
||||
START WITH name IN (select name from test_area where id < 3)
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
id | name | fatherid | name_desc | level | connect_by_isleaf | connect_by_iscycle | connect_by_root | sys_connect_by_path
|
||||
----+--------+----------+-----------+-------+-------------------+--------------------+-----------------+------------------------------------
|
||||
1 | 中国 | 0 | China | 1 | 0 | 0 | China | /China
|
||||
2 | 湖南省 | 1 | Hunan | 1 | 0 | 0 | Hunan | /Hunan
|
||||
2 | 湖南省 | 1 | Hunan | 2 | 0 | 0 | China | /China/Hunan
|
||||
3 | 广东省 | 1 | Guangdong | 2 | 0 | 0 | China | /China/Guangdong
|
||||
4 | 海南省 | 1 | Hainan | 2 | 1 | 0 | China | /China/Hainan
|
||||
5 | 河北省 | 1 | Hebei | 2 | 1 | 0 | China | /China/Hebei
|
||||
6 | 河南省 | 1 | Henan | 2 | 1 | 0 | China | /China/Henan
|
||||
7 | 山东省 | 1 | Shandong | 2 | 1 | 0 | China | /China/Shandong
|
||||
8 | 湖北省 | 1 | Hubei | 2 | 1 | 0 | China | /China/Hubei
|
||||
9 | 江苏省 | 1 | Jiangsu | 2 | 1 | 0 | China | /China/Jiangsu
|
||||
11 | 长沙市 | 2 | Changsha | 2 | 1 | 0 | Hunan | /Hunan/Changsha
|
||||
13 | 衡阳市 | 2 | Hengyang | 2 | 0 | 0 | Hunan | /Hunan/Hengyang
|
||||
10 | 深圳市 | 3 | Shenzhen | 3 | 0 | 0 | China | /China/Guangdong/Shenzhen
|
||||
11 | 长沙市 | 2 | Changsha | 3 | 1 | 0 | China | /China/Hunan/Changsha
|
||||
22 | 祁北县 | 13 | Qibei | 3 | 1 | 0 | Hunan | /Hunan/Hengyang/Qibei
|
||||
21 | 祁西县 | 13 | Qixi | 3 | 1 | 0 | Hunan | /Hunan/Hengyang/Qixi
|
||||
13 | 衡阳市 | 2 | Hengyang | 3 | 0 | 0 | China | /China/Hunan/Hengyang
|
||||
14 | 耒阳市 | 13 | Leiyang | 3 | 1 | 0 | Hunan | /Hunan/Hengyang/Leiyang
|
||||
19 | 祁东县 | 13 | Qidong | 3 | 1 | 0 | Hunan | /Hunan/Hengyang/Qidong
|
||||
18 | 常宁市 | 13 | Changning | 3 | 1 | 0 | Hunan | /Hunan/Hengyang/Changning
|
||||
20 | 祁南县 | 13 | Qinan | 3 | 1 | 0 | Hunan | /Hunan/Hengyang/Qinan
|
||||
22 | 祁北县 | 13 | Qibei | 4 | 1 | 0 | China | /China/Hunan/Hengyang/Qibei
|
||||
12 | 南山区 | 10 | Nanshan | 4 | 1 | 0 | China | /China/Guangdong/Shenzhen/Nanshan
|
||||
21 | 祁西县 | 13 | Qixi | 4 | 1 | 0 | China | /China/Hunan/Hengyang/Qixi
|
||||
14 | 耒阳市 | 13 | Leiyang | 4 | 1 | 0 | China | /China/Hunan/Hengyang/Leiyang
|
||||
15 | 龙岗区 | 10 | Longgang | 4 | 1 | 0 | China | /China/Guangdong/Shenzhen/Longgang
|
||||
16 | 福田区 | 10 | Futian | 4 | 1 | 0 | China | /China/Guangdong/Shenzhen/Futian
|
||||
17 | 宝安区 | 10 | Baoan | 4 | 1 | 0 | China | /China/Guangdong/Shenzhen/Baoan
|
||||
19 | 祁东县 | 13 | Qidong | 4 | 1 | 0 | China | /China/Hunan/Hengyang/Qidong
|
||||
18 | 常宁市 | 13 | Changning | 4 | 1 | 0 | China | /China/Hunan/Hengyang/Changning
|
||||
20 | 祁南县 | 13 | Qinan | 4 | 1 | 0 | China | /China/Hunan/Hengyang/Qinan
|
||||
(31 rows)
|
||||
|
||||
/*
|
||||
* 用例2.2,基础用例包含所有伪列, 包含多字符拼接,多条查找链,startwith使用IN子查询进行查找,结果集进行伪列过滤
|
||||
**/
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '/')
|
||||
FROM test_area
|
||||
WHERE LEVEL > 2
|
||||
START WITH name IN (select name from test_area where id < 3)
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
Filter: (level > 2)
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1, array_col_4
|
||||
-> Recursive Union
|
||||
-> Hash Semi Join
|
||||
Hash Cond: (swtest.test_area.name = swtest.test_area.name)
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> Seq Scan on test_area
|
||||
Filter: (id < 3)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.fatherid = tmp_reuslt."test_area@id")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(17 rows)
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '/')
|
||||
FROM test_area
|
||||
WHERE LEVEL > 2
|
||||
START WITH name IN (select name from test_area where id < 3)
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
id | name | fatherid | name_desc | level | connect_by_isleaf | connect_by_iscycle | connect_by_root | sys_connect_by_path
|
||||
----+--------+----------+-----------+-------+-------------------+--------------------+-----------------+------------------------------------
|
||||
10 | 深圳市 | 3 | Shenzhen | 3 | 0 | 0 | China | /China/Guangdong/Shenzhen
|
||||
11 | 长沙市 | 2 | Changsha | 3 | 1 | 0 | China | /China/Hunan/Changsha
|
||||
22 | 祁北县 | 13 | Qibei | 3 | 1 | 0 | Hunan | /Hunan/Hengyang/Qibei
|
||||
21 | 祁西县 | 13 | Qixi | 3 | 1 | 0 | Hunan | /Hunan/Hengyang/Qixi
|
||||
13 | 衡阳市 | 2 | Hengyang | 3 | 0 | 0 | China | /China/Hunan/Hengyang
|
||||
14 | 耒阳市 | 13 | Leiyang | 3 | 1 | 0 | Hunan | /Hunan/Hengyang/Leiyang
|
||||
19 | 祁东县 | 13 | Qidong | 3 | 1 | 0 | Hunan | /Hunan/Hengyang/Qidong
|
||||
18 | 常宁市 | 13 | Changning | 3 | 1 | 0 | Hunan | /Hunan/Hengyang/Changning
|
||||
20 | 祁南县 | 13 | Qinan | 3 | 1 | 0 | Hunan | /Hunan/Hengyang/Qinan
|
||||
22 | 祁北县 | 13 | Qibei | 4 | 1 | 0 | China | /China/Hunan/Hengyang/Qibei
|
||||
12 | 南山区 | 10 | Nanshan | 4 | 1 | 0 | China | /China/Guangdong/Shenzhen/Nanshan
|
||||
21 | 祁西县 | 13 | Qixi | 4 | 1 | 0 | China | /China/Hunan/Hengyang/Qixi
|
||||
14 | 耒阳市 | 13 | Leiyang | 4 | 1 | 0 | China | /China/Hunan/Hengyang/Leiyang
|
||||
15 | 龙岗区 | 10 | Longgang | 4 | 1 | 0 | China | /China/Guangdong/Shenzhen/Longgang
|
||||
16 | 福田区 | 10 | Futian | 4 | 1 | 0 | China | /China/Guangdong/Shenzhen/Futian
|
||||
17 | 宝安区 | 10 | Baoan | 4 | 1 | 0 | China | /China/Guangdong/Shenzhen/Baoan
|
||||
19 | 祁东县 | 13 | Qidong | 4 | 1 | 0 | China | /China/Hunan/Hengyang/Qidong
|
||||
18 | 常宁市 | 13 | Changning | 4 | 1 | 0 | China | /China/Hunan/Hengyang/Changning
|
||||
20 | 祁南县 | 13 | Qinan | 4 | 1 | 0 | China | /China/Hunan/Hengyang/Qinan
|
||||
(19 rows)
|
||||
|
||||
/*
|
||||
* 用例2.3,基础用例包含所有伪列, 包含多字符拼接,多条查找链,startwith使用IN子查询进行查找,结果集进行多个伪列过滤
|
||||
**/
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '/')
|
||||
FROM test_area
|
||||
WHERE LEVEL > 2 AND connect_by_iscycle IS NOT NULL
|
||||
START WITH name IN (select name from test_area where id < 3)
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
Filter: ((connect_by_iscycle IS NOT NULL) AND (level > 2))
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1, array_col_4
|
||||
-> Recursive Union
|
||||
-> Hash Semi Join
|
||||
Hash Cond: (swtest.test_area.name = swtest.test_area.name)
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> Seq Scan on test_area
|
||||
Filter: (id < 3)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.fatherid = tmp_reuslt."test_area@id")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(17 rows)
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '/')
|
||||
FROM test_area
|
||||
WHERE LEVEL > 2 AND connect_by_iscycle IS NOT NULL
|
||||
START WITH name IN (select name from test_area where id < 3)
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
id | name | fatherid | name_desc | level | connect_by_isleaf | connect_by_iscycle | connect_by_root | sys_connect_by_path
|
||||
----+--------+----------+-----------+-------+-------------------+--------------------+-----------------+------------------------------------
|
||||
10 | 深圳市 | 3 | Shenzhen | 3 | 0 | 0 | China | /China/Guangdong/Shenzhen
|
||||
11 | 长沙市 | 2 | Changsha | 3 | 1 | 0 | China | /China/Hunan/Changsha
|
||||
22 | 祁北县 | 13 | Qibei | 3 | 1 | 0 | Hunan | /Hunan/Hengyang/Qibei
|
||||
21 | 祁西县 | 13 | Qixi | 3 | 1 | 0 | Hunan | /Hunan/Hengyang/Qixi
|
||||
13 | 衡阳市 | 2 | Hengyang | 3 | 0 | 0 | China | /China/Hunan/Hengyang
|
||||
14 | 耒阳市 | 13 | Leiyang | 3 | 1 | 0 | Hunan | /Hunan/Hengyang/Leiyang
|
||||
19 | 祁东县 | 13 | Qidong | 3 | 1 | 0 | Hunan | /Hunan/Hengyang/Qidong
|
||||
18 | 常宁市 | 13 | Changning | 3 | 1 | 0 | Hunan | /Hunan/Hengyang/Changning
|
||||
20 | 祁南县 | 13 | Qinan | 3 | 1 | 0 | Hunan | /Hunan/Hengyang/Qinan
|
||||
22 | 祁北县 | 13 | Qibei | 4 | 1 | 0 | China | /China/Hunan/Hengyang/Qibei
|
||||
12 | 南山区 | 10 | Nanshan | 4 | 1 | 0 | China | /China/Guangdong/Shenzhen/Nanshan
|
||||
21 | 祁西县 | 13 | Qixi | 4 | 1 | 0 | China | /China/Hunan/Hengyang/Qixi
|
||||
14 | 耒阳市 | 13 | Leiyang | 4 | 1 | 0 | China | /China/Hunan/Hengyang/Leiyang
|
||||
15 | 龙岗区 | 10 | Longgang | 4 | 1 | 0 | China | /China/Guangdong/Shenzhen/Longgang
|
||||
16 | 福田区 | 10 | Futian | 4 | 1 | 0 | China | /China/Guangdong/Shenzhen/Futian
|
||||
17 | 宝安区 | 10 | Baoan | 4 | 1 | 0 | China | /China/Guangdong/Shenzhen/Baoan
|
||||
19 | 祁东县 | 13 | Qidong | 4 | 1 | 0 | China | /China/Hunan/Hengyang/Qidong
|
||||
18 | 常宁市 | 13 | Changning | 4 | 1 | 0 | China | /China/Hunan/Hengyang/Changning
|
||||
20 | 祁南县 | 13 | Qinan | 4 | 1 | 0 | China | /China/Hunan/Hengyang/Qinan
|
||||
(19 rows)
|
||||
|
||||
-- 三、 打开guc enable_startwith_debug = on测试
|
||||
/* DFX test, verify if */
|
||||
set enable_startwith_debug=on;
|
||||
set client_min_messages=log;
|
||||
explain (costs off)
|
||||
select *, LEVEL, CONNECT_BY_ROOT(name_desc), SYS_CONNECT_BY_PATH(name, '/') cpath from test_area
|
||||
START WITH name = '耒阳市'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
LOG: statement: explain (costs off)
|
||||
select *, LEVEL, CONNECT_BY_ROOT(name_desc), SYS_CONNECT_BY_PATH(name, '/') cpath from test_area
|
||||
START WITH name = '耒阳市'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
LOG: Accept a other Const val when evaluate FakeConst to rownum/level
|
||||
WARNING: Pushdown pseudo_tlist >>>>> [ -> WorkTableScan(tlist_len:12) -> Hash(tlist_len:12) -> HashJoin(tlist_len:12) -> RecursiveUnion(tlist_len:12)]
|
||||
WARNING: Pushdown pseudo_tlist >>>>> [ -> CteScan(tlist_len:11)]
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_3, array_col_2, array_col_4
|
||||
-> Recursive Union
|
||||
-> Seq Scan on test_area
|
||||
Filter: (name = '耒阳市'::text)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.id = tmp_reuslt."test_area@fatherid")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(12 rows)
|
||||
|
||||
select *, LEVEL, CONNECT_BY_ROOT(name_desc), SYS_CONNECT_BY_PATH(name, '/') cpath from test_area
|
||||
START WITH name = '耒阳市'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
LOG: statement: select *, LEVEL, CONNECT_BY_ROOT(name_desc), SYS_CONNECT_BY_PATH(name, '/') cpath from test_area
|
||||
START WITH name = '耒阳市'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
LOG: Accept a other Const val when evaluate FakeConst to rownum/level
|
||||
WARNING: Pushdown pseudo_tlist >>>>> [ -> WorkTableScan(tlist_len:12) -> Hash(tlist_len:12) -> HashJoin(tlist_len:12) -> RecursiveUnion(tlist_len:12)]
|
||||
WARNING: Pushdown pseudo_tlist >>>>> [ -> CteScan(tlist_len:11)]
|
||||
LOG: StartWithDebug: LEVEL:1 array_key_1:/{13}
|
||||
LOG: StartWithDebug: LEVEL:2 array_key_1:/{13}/{2}
|
||||
LOG: StartWithDebug: LEVEL:3 array_key_1:/{13}/{2}/{1}
|
||||
LOG: StartWithDebug: LEVEL:4 array_key_1:/{13}/{2}/{1}/{0}
|
||||
id | name | fatherid | name_desc | level | connect_by_root | cpath | RUITR | array_key_3 | array_col_2 | array_col_4
|
||||
----+--------+----------+-----------+-------+-----------------+----------------------------+-------+-------------------+----------------------------+-------------------------------
|
||||
14 | 耒阳市 | 13 | Leiyang | 1 | Leiyang | /耒阳市 | 0 | /{13} | /耒阳市 | /Leiyang
|
||||
13 | 衡阳市 | 2 | Hengyang | 2 | Leiyang | /耒阳市/衡阳市 | 1 | /{13}/{2} | /耒阳市/衡阳市 | /Leiyang/Hengyang
|
||||
2 | 湖南省 | 1 | Hunan | 3 | Leiyang | /耒阳市/衡阳市/湖南省 | 2 | /{13}/{2}/{1} | /耒阳市/衡阳市/湖南省 | /Leiyang/Hengyang/Hunan
|
||||
1 | 中国 | 0 | China | 4 | Leiyang | /耒阳市/衡阳市/湖南省/中国 | 3 | /{13}/{2}/{1}/{0} | /耒阳市/衡阳市/湖南省/中国 | /Leiyang/Hengyang/Hunan/China
|
||||
(4 rows)
|
||||
|
||||
explain (costs off)
|
||||
select *, LEVEL, CONNECT_BY_ROOT(name_desc), SYS_CONNECT_BY_PATH(name, '/') cpath from test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
order siblings by id;
|
||||
LOG: statement: explain (costs off)
|
||||
select *, LEVEL, CONNECT_BY_ROOT(name_desc), SYS_CONNECT_BY_PATH(name, '/') cpath from test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
order siblings by id;
|
||||
LOG: Accept a other Const val when evaluate FakeConst to rownum/level
|
||||
WARNING: Good we got siblings sort key under RU.
|
||||
WARNING: Good we got siblings sort key under RU.
|
||||
WARNING: Good we got siblings sort key above RU.
|
||||
WARNING: Pushdown pseudo_tlist >>>>> [ -> WorkTableScan(tlist_len:13) -> Hash(tlist_len:13) -> HashJoin(tlist_len:13) -> Sort(tlist_len:13) -> RecursiveUnion(tlist_len:13)]
|
||||
WARNING: Pushdown pseudo_tlist >>>>> [ -> CteScan(tlist_len:12)]
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1, array_col_2, array_col_4, array_siblings
|
||||
-> Sort
|
||||
Sort Key: array_siblings
|
||||
-> Recursive Union
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id
|
||||
-> Seq Scan on test_area
|
||||
Filter: (name = '中国'::text)
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.fatherid = tmp_reuslt."test_area@id")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(18 rows)
|
||||
|
||||
select *, LEVEL, CONNECT_BY_ROOT(name_desc), SYS_CONNECT_BY_PATH(name, '/') cpath from test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
order siblings by id;
|
||||
LOG: statement: select *, LEVEL, CONNECT_BY_ROOT(name_desc), SYS_CONNECT_BY_PATH(name, '/') cpath from test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
order siblings by id;
|
||||
LOG: Accept a other Const val when evaluate FakeConst to rownum/level
|
||||
WARNING: Good we got siblings sort key under RU.
|
||||
WARNING: Good we got siblings sort key under RU.
|
||||
WARNING: Good we got siblings sort key above RU.
|
||||
WARNING: Pushdown pseudo_tlist >>>>> [ -> WorkTableScan(tlist_len:13) -> Hash(tlist_len:13) -> HashJoin(tlist_len:13) -> Sort(tlist_len:13) -> RecursiveUnion(tlist_len:13)]
|
||||
WARNING: Pushdown pseudo_tlist >>>>> [ -> CteScan(tlist_len:12)]
|
||||
LOG: siblings key is \x01000000 current level is 1 tuple position is 1.
|
||||
LOG: StartWithDebug: LEVEL:1 array_key_1:/{1}
|
||||
LOG: siblings key is \x0100000001000000 current level is 2 tuple position is 1
|
||||
LOG: StartWithDebug: LEVEL:2 array_key_1:/{1}/{2}
|
||||
LOG: siblings key is \x0100000002000000 current level is 2 tuple position is 2
|
||||
LOG: StartWithDebug: LEVEL:2 array_key_1:/{1}/{3}
|
||||
LOG: siblings key is \x0100000003000000 current level is 2 tuple position is 3
|
||||
LOG: StartWithDebug: LEVEL:2 array_key_1:/{1}/{4}
|
||||
LOG: siblings key is \x0100000004000000 current level is 2 tuple position is 4
|
||||
LOG: StartWithDebug: LEVEL:2 array_key_1:/{1}/{5}
|
||||
LOG: siblings key is \x0100000005000000 current level is 2 tuple position is 5
|
||||
LOG: StartWithDebug: LEVEL:2 array_key_1:/{1}/{6}
|
||||
LOG: siblings key is \x0100000006000000 current level is 2 tuple position is 6
|
||||
LOG: StartWithDebug: LEVEL:2 array_key_1:/{1}/{7}
|
||||
LOG: siblings key is \x0100000007000000 current level is 2 tuple position is 7
|
||||
LOG: StartWithDebug: LEVEL:2 array_key_1:/{1}/{8}
|
||||
LOG: siblings key is \x0100000008000000 current level is 2 tuple position is 8
|
||||
LOG: StartWithDebug: LEVEL:2 array_key_1:/{1}/{9}
|
||||
LOG: siblings key is \x010000000200000001000000 current level is 3 tuple position is 1
|
||||
LOG: StartWithDebug: LEVEL:3 array_key_1:/{1}/{3}/{10}
|
||||
LOG: siblings key is \x010000000100000002000000 current level is 3 tuple position is 2
|
||||
LOG: StartWithDebug: LEVEL:3 array_key_1:/{1}/{2}/{11}
|
||||
LOG: siblings key is \x010000000100000003000000 current level is 3 tuple position is 3
|
||||
LOG: StartWithDebug: LEVEL:3 array_key_1:/{1}/{2}/{13}
|
||||
LOG: siblings key is \x01000000020000000100000001000000 current level is 4 tuple position is 1
|
||||
LOG: StartWithDebug: LEVEL:4 array_key_1:/{1}/{3}/{10}/{12}
|
||||
LOG: siblings key is \x01000000010000000300000002000000 current level is 4 tuple position is 2
|
||||
LOG: StartWithDebug: LEVEL:4 array_key_1:/{1}/{2}/{13}/{14}
|
||||
LOG: siblings key is \x01000000020000000100000003000000 current level is 4 tuple position is 3
|
||||
LOG: StartWithDebug: LEVEL:4 array_key_1:/{1}/{3}/{10}/{15}
|
||||
LOG: siblings key is \x01000000020000000100000004000000 current level is 4 tuple position is 4
|
||||
LOG: StartWithDebug: LEVEL:4 array_key_1:/{1}/{3}/{10}/{16}
|
||||
LOG: siblings key is \x01000000020000000100000005000000 current level is 4 tuple position is 5
|
||||
LOG: StartWithDebug: LEVEL:4 array_key_1:/{1}/{3}/{10}/{17}
|
||||
LOG: siblings key is \x01000000010000000300000006000000 current level is 4 tuple position is 6
|
||||
LOG: StartWithDebug: LEVEL:4 array_key_1:/{1}/{2}/{13}/{18}
|
||||
LOG: siblings key is \x01000000010000000300000007000000 current level is 4 tuple position is 7
|
||||
LOG: StartWithDebug: LEVEL:4 array_key_1:/{1}/{2}/{13}/{19}
|
||||
LOG: siblings key is \x01000000010000000300000008000000 current level is 4 tuple position is 8
|
||||
LOG: StartWithDebug: LEVEL:4 array_key_1:/{1}/{2}/{13}/{20}
|
||||
LOG: siblings key is \x01000000010000000300000009000000 current level is 4 tuple position is 9
|
||||
LOG: StartWithDebug: LEVEL:4 array_key_1:/{1}/{2}/{13}/{21}
|
||||
LOG: siblings key is \x0100000001000000030000000a000000 current level is 4 tuple position is 10
|
||||
LOG: StartWithDebug: LEVEL:4 array_key_1:/{1}/{2}/{13}/{22}
|
||||
id | name | fatherid | name_desc | level | connect_by_root | cpath | RUITR | array_key_1 | array_col_2 | array_col_4 | array_siblings
|
||||
----+--------+----------+-----------+-------+-----------------+----------------------------+-------+--------------------+----------------------------+------------------------------------+------------------------------------
|
||||
1 | 中国 | 0 | China | 1 | China | /中国 | 0 | /{1} | /中国 | /China | \x01000000
|
||||
2 | 湖南省 | 1 | Hunan | 2 | China | /中国/湖南省 | 1 | /{1}/{2} | /中国/湖南省 | /China/Hunan | \x0100000001000000
|
||||
11 | 长沙市 | 2 | Changsha | 3 | China | /中国/湖南省/长沙市 | 2 | /{1}/{2}/{11} | /中国/湖南省/长沙市 | /China/Hunan/Changsha | \x010000000100000002000000
|
||||
13 | 衡阳市 | 2 | Hengyang | 3 | China | /中国/湖南省/衡阳市 | 2 | /{1}/{2}/{13} | /中国/湖南省/衡阳市 | /China/Hunan/Hengyang | \x010000000100000003000000
|
||||
14 | 耒阳市 | 13 | Leiyang | 4 | China | /中国/湖南省/衡阳市/耒阳市 | 3 | /{1}/{2}/{13}/{14} | /中国/湖南省/衡阳市/耒阳市 | /China/Hunan/Hengyang/Leiyang | \x01000000010000000300000002000000
|
||||
18 | 常宁市 | 13 | Changning | 4 | China | /中国/湖南省/衡阳市/常宁市 | 3 | /{1}/{2}/{13}/{18} | /中国/湖南省/衡阳市/常宁市 | /China/Hunan/Hengyang/Changning | \x01000000010000000300000006000000
|
||||
19 | 祁东县 | 13 | Qidong | 4 | China | /中国/湖南省/衡阳市/祁东县 | 3 | /{1}/{2}/{13}/{19} | /中国/湖南省/衡阳市/祁东县 | /China/Hunan/Hengyang/Qidong | \x01000000010000000300000007000000
|
||||
20 | 祁南县 | 13 | Qinan | 4 | China | /中国/湖南省/衡阳市/祁南县 | 3 | /{1}/{2}/{13}/{20} | /中国/湖南省/衡阳市/祁南县 | /China/Hunan/Hengyang/Qinan | \x01000000010000000300000008000000
|
||||
21 | 祁西县 | 13 | Qixi | 4 | China | /中国/湖南省/衡阳市/祁西县 | 3 | /{1}/{2}/{13}/{21} | /中国/湖南省/衡阳市/祁西县 | /China/Hunan/Hengyang/Qixi | \x01000000010000000300000009000000
|
||||
22 | 祁北县 | 13 | Qibei | 4 | China | /中国/湖南省/衡阳市/祁北县 | 3 | /{1}/{2}/{13}/{22} | /中国/湖南省/衡阳市/祁北县 | /China/Hunan/Hengyang/Qibei | \x0100000001000000030000000a000000
|
||||
3 | 广东省 | 1 | Guangdong | 2 | China | /中国/广东省 | 1 | /{1}/{3} | /中国/广东省 | /China/Guangdong | \x0100000002000000
|
||||
10 | 深圳市 | 3 | Shenzhen | 3 | China | /中国/广东省/深圳市 | 2 | /{1}/{3}/{10} | /中国/广东省/深圳市 | /China/Guangdong/Shenzhen | \x010000000200000001000000
|
||||
12 | 南山区 | 10 | Nanshan | 4 | China | /中国/广东省/深圳市/南山区 | 3 | /{1}/{3}/{10}/{12} | /中国/广东省/深圳市/南山区 | /China/Guangdong/Shenzhen/Nanshan | \x01000000020000000100000001000000
|
||||
15 | 龙岗区 | 10 | Longgang | 4 | China | /中国/广东省/深圳市/龙岗区 | 3 | /{1}/{3}/{10}/{15} | /中国/广东省/深圳市/龙岗区 | /China/Guangdong/Shenzhen/Longgang | \x01000000020000000100000003000000
|
||||
16 | 福田区 | 10 | Futian | 4 | China | /中国/广东省/深圳市/福田区 | 3 | /{1}/{3}/{10}/{16} | /中国/广东省/深圳市/福田区 | /China/Guangdong/Shenzhen/Futian | \x01000000020000000100000004000000
|
||||
17 | 宝安区 | 10 | Baoan | 4 | China | /中国/广东省/深圳市/宝安区 | 3 | /{1}/{3}/{10}/{17} | /中国/广东省/深圳市/宝安区 | /China/Guangdong/Shenzhen/Baoan | \x01000000020000000100000005000000
|
||||
4 | 海南省 | 1 | Hainan | 2 | China | /中国/海南省 | 1 | /{1}/{4} | /中国/海南省 | /China/Hainan | \x0100000003000000
|
||||
5 | 河北省 | 1 | Hebei | 2 | China | /中国/河北省 | 1 | /{1}/{5} | /中国/河北省 | /China/Hebei | \x0100000004000000
|
||||
6 | 河南省 | 1 | Henan | 2 | China | /中国/河南省 | 1 | /{1}/{6} | /中国/河南省 | /China/Henan | \x0100000005000000
|
||||
7 | 山东省 | 1 | Shandong | 2 | China | /中国/山东省 | 1 | /{1}/{7} | /中国/山东省 | /China/Shandong | \x0100000006000000
|
||||
8 | 湖北省 | 1 | Hubei | 2 | China | /中国/湖北省 | 1 | /{1}/{8} | /中国/湖北省 | /China/Hubei | \x0100000007000000
|
||||
9 | 江苏省 | 1 | Jiangsu | 2 | China | /中国/江苏省 | 1 | /{1}/{9} | /中国/江苏省 | /China/Jiangsu | \x0100000008000000
|
||||
(22 rows)
|
||||
|
||||
reset enable_startwith_debug;
|
||||
LOG: statement: reset enable_startwith_debug;
|
||||
reset client_min_messages;
|
||||
LOG: statement: reset client_min_messages;
|
||||
2510
src/test/regress/expected/sw_bugfix.out
Normal file
2510
src/test/regress/expected/sw_bugfix.out
Normal file
File diff suppressed because it is too large
Load Diff
180
src/test/regress/expected/sw_by_rownum_level.out
Normal file
180
src/test/regress/expected/sw_by_rownum_level.out
Normal file
@ -0,0 +1,180 @@
|
||||
set client_min_messages = error;
|
||||
set search_path=swtest;
|
||||
SET CLIENT_ENCODING='UTF8';
|
||||
--accepted cases
|
||||
explain (costs off)
|
||||
select * from test_area CONNECT BY LEVEL <= LENGTH('SOME TEXT');
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR
|
||||
-> Recursive Union
|
||||
-> Seq Scan on test_area
|
||||
-> Nested Loop
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> Materialize
|
||||
-> Seq Scan on test_area
|
||||
(10 rows)
|
||||
|
||||
explain (costs off)
|
||||
select *, LEVEL from test_area CONNECT BY LEVEL <= LENGTH('SOME TEXT');
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR
|
||||
-> Recursive Union
|
||||
-> Seq Scan on test_area
|
||||
-> Nested Loop
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> Materialize
|
||||
-> Seq Scan on test_area
|
||||
(10 rows)
|
||||
|
||||
explain (costs off)
|
||||
select * from test_area CONNECT BY ROWNUM <= LENGTH('SOME TEXT');
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR
|
||||
-> Recursive Union
|
||||
-> Seq Scan on test_area
|
||||
-> Nested Loop
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> Materialize
|
||||
-> Seq Scan on test_area
|
||||
(10 rows)
|
||||
|
||||
explain (costs off)
|
||||
select *, ROWNUM from test_area CONNECT BY ROWNUM <= LENGTH('SOME TEXT');
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR
|
||||
-> Recursive Union
|
||||
-> Seq Scan on test_area
|
||||
-> Nested Loop
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> Materialize
|
||||
-> Seq Scan on test_area
|
||||
(10 rows)
|
||||
|
||||
explain (costs off)
|
||||
select * from test_area CONNECT BY LEVEL < LENGTH('SOME TEXT');
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR
|
||||
-> Recursive Union
|
||||
-> Seq Scan on test_area
|
||||
-> Nested Loop
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> Materialize
|
||||
-> Seq Scan on test_area
|
||||
(10 rows)
|
||||
|
||||
explain (costs off)
|
||||
select *, LEVEL from test_area CONNECT BY LEVEL < LENGTH('SOME TEXT');
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR
|
||||
-> Recursive Union
|
||||
-> Seq Scan on test_area
|
||||
-> Nested Loop
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> Materialize
|
||||
-> Seq Scan on test_area
|
||||
(10 rows)
|
||||
|
||||
explain (costs off)
|
||||
select * from test_area CONNECT BY ROWNUM < LENGTH('SOME TEXT');
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR
|
||||
-> Recursive Union
|
||||
-> Seq Scan on test_area
|
||||
-> Nested Loop
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> Materialize
|
||||
-> Seq Scan on test_area
|
||||
(10 rows)
|
||||
|
||||
explain (costs off)
|
||||
select *, ROWNUM from test_area CONNECT BY ROWNUM < LENGTH('SOME TEXT');
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR
|
||||
-> Recursive Union
|
||||
-> Seq Scan on test_area
|
||||
-> Nested Loop
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> Materialize
|
||||
-> Seq Scan on test_area
|
||||
(10 rows)
|
||||
|
||||
--rejected cases
|
||||
explain (costs off)
|
||||
select *, LEVEL from test_area CONNECT BY LEVEL > LENGTH('SOME TEXT');
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR
|
||||
-> Recursive Union
|
||||
-> Seq Scan on test_area
|
||||
-> Nested Loop
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> Materialize
|
||||
-> Seq Scan on test_area
|
||||
(10 rows)
|
||||
|
||||
explain (costs off)
|
||||
select *, LEVEL from test_area CONNECT BY LEVEL >= LENGTH('SOME TEXT');
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR
|
||||
-> Recursive Union
|
||||
-> Seq Scan on test_area
|
||||
-> Nested Loop
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> Materialize
|
||||
-> Seq Scan on test_area
|
||||
(10 rows)
|
||||
|
||||
explain (costs off)
|
||||
select * from test_area CONNECT BY APPLE > LENGTH('SOME TEXT');
|
||||
ERROR: column "apple" does not exist
|
||||
LINE 2: select * from test_area CONNECT BY APPLE > LENGTH('SOME TEXT...
|
||||
^
|
||||
explain (costs off)
|
||||
select * from test_area CONNECT BY APPLE < LENGTH('SOME TEXT');
|
||||
ERROR: column "apple" does not exist
|
||||
LINE 2: select * from test_area CONNECT BY APPLE < LENGTH('SOME TEXT...
|
||||
^
|
||||
explain (costs off)
|
||||
select * from test_area CONNECT BY APPLE <= LENGTH('SOME TEXT');
|
||||
ERROR: column "apple" does not exist
|
||||
LINE 2: select * from test_area CONNECT BY APPLE <= LENGTH('SOME TEX...
|
||||
^
|
||||
15
src/test/regress/expected/sw_clearup.out
Normal file
15
src/test/regress/expected/sw_clearup.out
Normal file
@ -0,0 +1,15 @@
|
||||
set current_schema=swtest;
|
||||
drop table if exists swtest.test_area;
|
||||
drop table if exists swtest.test_area2;
|
||||
drop table if exists swtest.t1;
|
||||
drop table if exists swtest.t2;
|
||||
drop table if exists swtest.test_hcb_ptb;
|
||||
drop table if exists swtest.test_hcb_fqb;
|
||||
drop table if exists swtest.test_sublink;
|
||||
drop table if exists swtest.test_hcb_ptbc;
|
||||
drop table if exists swtest.test_swcb_a;
|
||||
drop table if exists swtest.trait_value;
|
||||
drop table if exists swtest.offers_20050701;
|
||||
drop table if exists swtest.brand;
|
||||
drop schema if exists swtest cascade;
|
||||
NOTICE: drop cascades to view dual
|
||||
553
src/test/regress/expected/sw_icbc.out
Normal file
553
src/test/regress/expected/sw_icbc.out
Normal file
@ -0,0 +1,553 @@
|
||||
set client_min_messages = error;
|
||||
set search_path=swtest;
|
||||
SET CLIENT_ENCODING='UTF8';
|
||||
--signle table columns test
|
||||
explain (costs off)
|
||||
select * from t1 start with id = 1 connect by prior id = pid;
|
||||
QUERY PLAN
|
||||
-----------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1
|
||||
-> Recursive Union
|
||||
-> Seq Scan on t1
|
||||
Filter: (id = 1)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.t1.pid = tmp_reuslt."t1@id")
|
||||
-> Seq Scan on t1
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(12 rows)
|
||||
|
||||
select * from t1 start with id = 1 connect by prior id = pid;
|
||||
id | pid | name
|
||||
----+-----+------
|
||||
1 | 0 | 1
|
||||
2 | 1 | 2
|
||||
4 | 1 | 4
|
||||
5 | 2 | 5
|
||||
7 | 4 | 7
|
||||
8 | 4 | 8
|
||||
9 | 7 | 9
|
||||
(7 rows)
|
||||
|
||||
explain (costs off)
|
||||
select * from t1 start with t1.id = 1 connect by prior t1.id = t1.pid;
|
||||
QUERY PLAN
|
||||
-----------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1
|
||||
-> Recursive Union
|
||||
-> Seq Scan on t1
|
||||
Filter: (id = 1)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.t1.pid = tmp_reuslt."t1@id")
|
||||
-> Seq Scan on t1
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(12 rows)
|
||||
|
||||
select * from t1 start with t1.id = 1 connect by prior t1.id = t1.pid;
|
||||
id | pid | name
|
||||
----+-----+------
|
||||
1 | 0 | 1
|
||||
2 | 1 | 2
|
||||
4 | 1 | 4
|
||||
5 | 2 | 5
|
||||
7 | 4 | 7
|
||||
8 | 4 | 8
|
||||
9 | 7 | 9
|
||||
(7 rows)
|
||||
|
||||
explain (costs off)
|
||||
select * from t1 as test start with test.id = 1 connect by prior test.id = test.pid;
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1
|
||||
-> Recursive Union
|
||||
-> Seq Scan on t1 test
|
||||
Filter: (id = 1)
|
||||
-> Hash Join
|
||||
Hash Cond: (test.pid = tmp_reuslt."test@id")
|
||||
-> Seq Scan on t1 test
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(12 rows)
|
||||
|
||||
select * from t1 as test start with test.id = 1 connect by prior test.id = test.pid;
|
||||
id | pid | name
|
||||
----+-----+------
|
||||
1 | 0 | 1
|
||||
2 | 1 | 2
|
||||
4 | 1 | 4
|
||||
5 | 2 | 5
|
||||
7 | 4 | 7
|
||||
8 | 4 | 8
|
||||
9 | 7 | 9
|
||||
(7 rows)
|
||||
|
||||
explain (costs off)
|
||||
select * from t1 start with id = 1 connect by prior id = pid order by id desc;
|
||||
QUERY PLAN
|
||||
-----------------------------------------------------------------------
|
||||
Sort
|
||||
Sort Key: tmp_reuslt."t1@id" DESC
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1
|
||||
-> Recursive Union
|
||||
-> Seq Scan on t1
|
||||
Filter: (id = 1)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.t1.pid = tmp_reuslt."t1@id")
|
||||
-> Seq Scan on t1
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> CTE Scan on tmp_reuslt
|
||||
(14 rows)
|
||||
|
||||
select * from t1 start with id = 1 connect by prior id = pid order by id desc;
|
||||
id | pid | name
|
||||
----+-----+------
|
||||
9 | 7 | 9
|
||||
8 | 4 | 8
|
||||
7 | 4 | 7
|
||||
5 | 2 | 5
|
||||
4 | 1 | 4
|
||||
2 | 1 | 2
|
||||
1 | 0 | 1
|
||||
(7 rows)
|
||||
|
||||
explain (costs off)
|
||||
select * from t1 start with id IN (select id from t2 where id = 1) connect by prior id = pid order by id desc;
|
||||
QUERY PLAN
|
||||
-----------------------------------------------------------------------
|
||||
Sort
|
||||
Sort Key: tmp_reuslt."t1@id" DESC
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1
|
||||
-> Recursive Union
|
||||
-> Nested Loop Semi Join
|
||||
-> Seq Scan on t1
|
||||
Filter: (id = 1)
|
||||
-> Seq Scan on t2
|
||||
Filter: (id = 1)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.t1.pid = tmp_reuslt."t1@id")
|
||||
-> Seq Scan on t1
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> CTE Scan on tmp_reuslt
|
||||
(17 rows)
|
||||
|
||||
select * from t1 start with id IN (select id from t2 where id = 1) connect by prior id = pid order by id desc;
|
||||
id | pid | name
|
||||
----+-----+------
|
||||
9 | 7 | 9
|
||||
8 | 4 | 8
|
||||
7 | 4 | 7
|
||||
5 | 2 | 5
|
||||
4 | 1 | 4
|
||||
2 | 1 | 2
|
||||
1 | 0 | 1
|
||||
(7 rows)
|
||||
|
||||
explain (costs off) select t1.id, t1.pid, t1.name from t1 start with id = 1 connect by prior id = pid;
|
||||
QUERY PLAN
|
||||
-----------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1
|
||||
-> Recursive Union
|
||||
-> Seq Scan on t1
|
||||
Filter: (id = 1)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.t1.pid = tmp_reuslt."t1@id")
|
||||
-> Seq Scan on t1
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(12 rows)
|
||||
|
||||
select t1.id, t1.pid, t1.name from t1 start with id = 1 connect by prior id = pid;
|
||||
id | pid | name
|
||||
----+-----+------
|
||||
1 | 0 | 1
|
||||
2 | 1 | 2
|
||||
4 | 1 | 4
|
||||
5 | 2 | 5
|
||||
7 | 4 | 7
|
||||
8 | 4 | 8
|
||||
9 | 7 | 9
|
||||
(7 rows)
|
||||
|
||||
explain (costs off) select sum(name) from t1 start with id = 1 connect by prior id = pid group by id, pid;
|
||||
QUERY PLAN
|
||||
-----------------------------------------------------------------------
|
||||
HashAggregate
|
||||
Group By Key: tmp_reuslt."t1@id", tmp_reuslt."t1@pid"
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1
|
||||
-> Recursive Union
|
||||
-> Seq Scan on t1
|
||||
Filter: (id = 1)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.t1.pid = tmp_reuslt."t1@id")
|
||||
-> Seq Scan on t1
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> CTE Scan on tmp_reuslt
|
||||
(14 rows)
|
||||
|
||||
select sum(name) from t1 start with id = 1 connect by prior id = pid group by id, pid;
|
||||
sum
|
||||
-----
|
||||
7
|
||||
4
|
||||
1
|
||||
9
|
||||
2
|
||||
5
|
||||
8
|
||||
(7 rows)
|
||||
|
||||
explain (costs off) select * from t1 start with id = 1 connect by prior id = pid and id IN (select id from t2);
|
||||
QUERY PLAN
|
||||
-----------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1
|
||||
-> Recursive Union
|
||||
-> Seq Scan on t1
|
||||
Filter: (id = 1)
|
||||
-> Hash Semi Join
|
||||
Hash Cond: (swtest.t1.id = t2.id)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.t1.pid = tmp_reuslt."t1@id")
|
||||
-> Seq Scan on t1
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> Hash
|
||||
-> Seq Scan on t2
|
||||
(16 rows)
|
||||
|
||||
select * from t1 start with id = 1 connect by prior id = pid and id IN (select id from t2);
|
||||
id | pid | name
|
||||
----+-----+------
|
||||
1 | 0 | 1
|
||||
2 | 1 | 2
|
||||
4 | 1 | 4
|
||||
5 | 2 | 5
|
||||
7 | 4 | 7
|
||||
8 | 4 | 8
|
||||
9 | 7 | 9
|
||||
(7 rows)
|
||||
|
||||
explain (costs off) select * from t1 start with id = 1 and id is not NULL connect by prior id = pid;
|
||||
QUERY PLAN
|
||||
-----------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1
|
||||
-> Recursive Union
|
||||
-> Seq Scan on t1
|
||||
Filter: ((id IS NOT NULL) AND (id = 1))
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.t1.pid = tmp_reuslt."t1@id")
|
||||
-> Seq Scan on t1
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(12 rows)
|
||||
|
||||
select * from t1 start with id = 1 and id is not NULL connect by prior id = pid;
|
||||
id | pid | name
|
||||
----+-----+------
|
||||
1 | 0 | 1
|
||||
2 | 1 | 2
|
||||
4 | 1 | 4
|
||||
5 | 2 | 5
|
||||
7 | 4 | 7
|
||||
8 | 4 | 8
|
||||
9 | 7 | 9
|
||||
(7 rows)
|
||||
|
||||
explain (costs off)
|
||||
select *
|
||||
from
|
||||
(select t1.id id, t1.pid pid, t1.name name from t1
|
||||
union
|
||||
select t1.id id, t1.pid pid, t1.name name from t1) as test
|
||||
start with test.id = 1
|
||||
connect by prior test.id = test.pid;
|
||||
QUERY PLAN
|
||||
---------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1
|
||||
-> Recursive Union
|
||||
-> Unique
|
||||
-> Sort
|
||||
Sort Key: swtest.t1.id, swtest.t1.pid, swtest.t1.name
|
||||
-> Append
|
||||
-> Seq Scan on t1
|
||||
Filter: (id = 1)
|
||||
-> Seq Scan on t1
|
||||
Filter: (id = 1)
|
||||
-> Hash Join
|
||||
Hash Cond: (tmp_reuslt."test@id" = swtest.t1.pid)
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> Hash
|
||||
-> HashAggregate
|
||||
Group By Key: swtest.t1.id, swtest.t1.pid, swtest.t1.name
|
||||
-> Append
|
||||
-> Seq Scan on t1
|
||||
-> Seq Scan on t1
|
||||
(22 rows)
|
||||
|
||||
select *
|
||||
from
|
||||
(select t1.id id, t1.pid pid, t1.name name from t1
|
||||
union
|
||||
select t1.id id, t1.pid pid, t1.name name from t1) as test
|
||||
start with test.id = 1
|
||||
connect by prior test.id = test.pid;
|
||||
id | pid | name
|
||||
----+-----+------
|
||||
1 | 0 | 1
|
||||
2 | 1 | 2
|
||||
4 | 1 | 4
|
||||
5 | 2 | 5
|
||||
7 | 4 | 7
|
||||
8 | 4 | 8
|
||||
9 | 7 | 9
|
||||
(7 rows)
|
||||
|
||||
explain (costs off)
|
||||
select *
|
||||
from
|
||||
(select *
|
||||
from(select t1.id id, t1.pid pid, t1.name name from t1
|
||||
union
|
||||
select t1.id id, t1.pid pid, t1.name name from t1) as test
|
||||
start with test.id = 1
|
||||
connect by prior test.id = test.pid) as tt
|
||||
CONNECT BY PRIOR tt.id = tt.pid
|
||||
START WITH tt.id = 1;
|
||||
QUERY PLAN
|
||||
-----------------------------------------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1
|
||||
-> Recursive Union
|
||||
-> CTE Scan on tmp_reuslt
|
||||
Filter: ("test@id" = 1)
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1
|
||||
-> Recursive Union
|
||||
-> Unique
|
||||
-> Sort
|
||||
Sort Key: swtest.t1.id, swtest.t1.pid, swtest.t1.name
|
||||
-> Append
|
||||
-> Seq Scan on t1
|
||||
Filter: (id = 1)
|
||||
-> Seq Scan on t1
|
||||
Filter: (id = 1)
|
||||
-> Hash Join
|
||||
Hash Cond: (tmp_reuslt."test@id" = swtest.t1.pid)
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> Hash
|
||||
-> HashAggregate
|
||||
Group By Key: swtest.t1.id, swtest.t1.pid, swtest.t1.name
|
||||
-> Append
|
||||
-> Seq Scan on t1
|
||||
-> Seq Scan on t1
|
||||
-> Hash Join
|
||||
Hash Cond: (tmp_reuslt."test@pid" = tmp_reuslt."tt@id")
|
||||
-> Materialize
|
||||
-> CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1
|
||||
-> Recursive Union
|
||||
-> Unique
|
||||
-> Sort
|
||||
Sort Key: swtest.t1.id, swtest.t1.pid, swtest.t1.name
|
||||
-> Append
|
||||
-> Seq Scan on t1
|
||||
Filter: (id = 1)
|
||||
-> Seq Scan on t1
|
||||
Filter: (id = 1)
|
||||
-> Hash Join
|
||||
Hash Cond: (tmp_reuslt."test@id" = swtest.t1.pid)
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> Hash
|
||||
-> HashAggregate
|
||||
Group By Key: swtest.t1.id, swtest.t1.pid, swtest.t1.name
|
||||
-> Append
|
||||
-> Seq Scan on t1
|
||||
-> Seq Scan on t1
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(55 rows)
|
||||
|
||||
select *
|
||||
from
|
||||
(select *
|
||||
from(select t1.id id, t1.pid pid, t1.name name from t1
|
||||
union
|
||||
select t1.id id, t1.pid pid, t1.name name from t1) as test
|
||||
start with test.id = 1
|
||||
connect by prior test.id = test.pid) as tt
|
||||
CONNECT BY PRIOR tt.id = tt.pid
|
||||
START WITH tt.id = 1;
|
||||
id | pid | name
|
||||
----+-----+------
|
||||
1 | 0 | 1
|
||||
2 | 1 | 2
|
||||
4 | 1 | 4
|
||||
5 | 2 | 5
|
||||
7 | 4 | 7
|
||||
8 | 4 | 8
|
||||
9 | 7 | 9
|
||||
(7 rows)
|
||||
|
||||
--test correlated sublink in targetlist
|
||||
explain select b.id, (select count(a.id) from t1 a where a.pid = b.id) c from t1 b
|
||||
start with b.id=1 connect by prior b.id = b.pid;
|
||||
QUERY PLAN
|
||||
-------------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt (cost=18.22..122.64 rows=91 width=4)
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator (cost=0.00..18.22 rows=91 width=10)
|
||||
Start With pseudo atts: RUITR, array_key_1
|
||||
-> Recursive Union (cost=0.00..18.22 rows=91 width=10)
|
||||
-> Seq Scan on t1 b (cost=0.00..1.11 rows=1 width=10)
|
||||
Filter: (id = 1)
|
||||
-> Hash Join (cost=0.33..1.53 rows=9 width=10)
|
||||
Hash Cond: (b.pid = tmp_reuslt."b@id")
|
||||
-> Seq Scan on t1 b (cost=0.00..1.09 rows=9 width=10)
|
||||
-> Hash (cost=0.20..0.20 rows=10 width=4)
|
||||
-> WorkTable Scan on tmp_reuslt (cost=0.00..0.20 rows=10 width=4)
|
||||
SubPlan 2
|
||||
-> Aggregate (cost=1.12..1.13 rows=1 width=12)
|
||||
-> Seq Scan on t1 a (cost=0.00..1.11 rows=2 width=4)
|
||||
Filter: (pid = tmp_reuslt."b@id")
|
||||
(16 rows)
|
||||
|
||||
explain select * from t1 as test
|
||||
where not exists (select 1 from t1 where test.id = t1.id)
|
||||
start with test.id = 1 connect by prior test.id = test.pid;
|
||||
QUERY PLAN
|
||||
-------------------------------------------------------------------------------------------------
|
||||
Hash Anti Join (cost=19.42..22.29 rows=82 width=40)
|
||||
Hash Cond: (tmp_reuslt."test@id" = t1.id)
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator (cost=0.00..18.22 rows=91 width=10)
|
||||
Start With pseudo atts: RUITR, array_key_1
|
||||
-> Recursive Union (cost=0.00..18.22 rows=91 width=10)
|
||||
-> Seq Scan on t1 test (cost=0.00..1.11 rows=1 width=10)
|
||||
Filter: (id = 1)
|
||||
-> Hash Join (cost=0.33..1.53 rows=9 width=10)
|
||||
Hash Cond: (test.pid = tmp_reuslt."test@id")
|
||||
-> Seq Scan on t1 test (cost=0.00..1.09 rows=9 width=10)
|
||||
-> Hash (cost=0.20..0.20 rows=10 width=4)
|
||||
-> WorkTable Scan on tmp_reuslt (cost=0.00..0.20 rows=10 width=4)
|
||||
-> CTE Scan on tmp_reuslt (cost=0.00..1.82 rows=91 width=40)
|
||||
-> Hash (cost=1.09..1.09 rows=9 width=4)
|
||||
-> Seq Scan on t1 (cost=0.00..1.09 rows=9 width=4)
|
||||
(16 rows)
|
||||
|
||||
--multiple tables case
|
||||
explain (costs off) select * from t1, t2 where t1.id = t2.id start with t1.id = t2.id and t1.id = 1 connect by prior t1.id = t1.pid;
|
||||
QUERY PLAN
|
||||
-----------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1
|
||||
-> Recursive Union
|
||||
-> Nested Loop
|
||||
-> Seq Scan on t1
|
||||
Filter: (id = 1)
|
||||
-> Seq Scan on t2
|
||||
Filter: (id = 1)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.t1.id = swtest.t2.id)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.t1.pid = tmp_reuslt."t1@id")
|
||||
-> Seq Scan on t1
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> Hash
|
||||
-> Seq Scan on t2
|
||||
(19 rows)
|
||||
|
||||
explain (costs off) select * from t1 join t2 on t1.id = t2.id start with t1.id = t2.id and t1.id = 1 connect by prior t1.id = t1.pid;
|
||||
QUERY PLAN
|
||||
-----------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1
|
||||
-> Recursive Union
|
||||
-> Nested Loop
|
||||
-> Seq Scan on t1
|
||||
Filter: (id = 1)
|
||||
-> Seq Scan on t2
|
||||
Filter: (id = 1)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.t1.id = swtest.t2.id)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.t1.pid = tmp_reuslt."t1@id")
|
||||
-> Seq Scan on t1
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> Hash
|
||||
-> Seq Scan on t2
|
||||
(19 rows)
|
||||
|
||||
explain (costs off) select * from t1, (select * from t2) as test where t1.id = test.id start with t1.id = test.id and t1.id = 1 connect by prior t1.id = t1.pid;
|
||||
QUERY PLAN
|
||||
-----------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1
|
||||
-> Recursive Union
|
||||
-> Nested Loop
|
||||
-> Seq Scan on t1
|
||||
Filter: (id = 1)
|
||||
-> Seq Scan on t2
|
||||
Filter: (id = 1)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.t1.id = swtest.t2.id)
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.t1.pid = tmp_reuslt."t1@id")
|
||||
-> Seq Scan on t1
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
-> Hash
|
||||
-> Seq Scan on t2
|
||||
(19 rows)
|
||||
|
||||
explain (costs off) select id, (select id from t2 start with t2.id = t1.id connect by t2.id = t1.id limit 1) from t1 where id = 1;
|
||||
ERROR: START WITH CONNECT BY clauses must have at least one prior key.
|
||||
--unsupport case
|
||||
select prior id cc from t1 start with id = 1 connect by prior id = pid;
|
||||
ERROR: Not Support prior column in TargetList in case swcb.
|
||||
create INCREMENTAL MATERIALIZED view mv as select * from t1 start with id=141 connect by prior id=pid;
|
||||
ERROR: Feature not supported
|
||||
DETAIL: with or start with clause
|
||||
229
src/test/regress/expected/sw_prepare.out
Normal file
229
src/test/regress/expected/sw_prepare.out
Normal file
@ -0,0 +1,229 @@
|
||||
drop schema if exists swtest cascade;
|
||||
NOTICE: schema "swtest" does not exist, skipping
|
||||
create schema swtest;
|
||||
set current_schema=swtest;
|
||||
drop table if exists swtest.test_area;
|
||||
NOTICE: table "test_area" does not exist, skipping
|
||||
drop table if exists swtest.test_area2;
|
||||
NOTICE: table "test_area2" does not exist, skipping
|
||||
drop table if exists swtest.t1;
|
||||
NOTICE: table "t1" does not exist, skipping
|
||||
drop table if exists swtest.t2;
|
||||
NOTICE: table "t2" does not exist, skipping
|
||||
drop table if exists swtest.test_hcb_ptb;
|
||||
NOTICE: table "test_hcb_ptb" does not exist, skipping
|
||||
drop table if exists swtest.test_hcb_fqb;
|
||||
NOTICE: table "test_hcb_fqb" does not exist, skipping
|
||||
drop table if exists swtest.test_sublink;
|
||||
NOTICE: table "test_sublink" does not exist, skipping
|
||||
drop table if exists swtest.test_hcb_ptbc;
|
||||
NOTICE: table "test_hcb_ptbc" does not exist, skipping
|
||||
drop table if exists swtest.test_swcb_a;
|
||||
NOTICE: table "test_swcb_a" does not exist, skipping
|
||||
drop table if exists swtest.trait_value;
|
||||
NOTICE: table "trait_value" does not exist, skipping
|
||||
drop table if exists swtest.offers_20050701;
|
||||
NOTICE: table "offers_20050701" does not exist, skipping
|
||||
drop table if exists swtest.brand;
|
||||
NOTICE: table "brand" does not exist, skipping
|
||||
create table swtest.test_area(id int4,name text, fatherid int4, name_desc text);
|
||||
insert into swtest.test_area values (1, '中国', 0, 'China');
|
||||
insert into swtest.test_area values (2, '湖南省',1 , 'Hunan');
|
||||
insert into swtest.test_area values (3, '广东省',1 , 'Guangdong');
|
||||
insert into swtest.test_area values (4, '海南省',1 , 'Hainan');
|
||||
insert into swtest.test_area values (5, '河北省',1 , 'Hebei');
|
||||
insert into swtest.test_area values (6, '河南省',1 , 'Henan');
|
||||
insert into swtest.test_area values (7, '山东省',1 , 'Shandong');
|
||||
insert into swtest.test_area values (8, '湖北省',1 , 'Hubei');
|
||||
insert into swtest.test_area values (9, '江苏省',1 , 'Jiangsu');
|
||||
insert into swtest.test_area values (10,'深圳市',3 , 'Shenzhen');
|
||||
insert into swtest.test_area values (11,'长沙市',2 , 'Changsha');
|
||||
insert into swtest.test_area values (22,'祁北县',13, 'Qibei');
|
||||
insert into swtest.test_area values (12,'南山区',10, 'Nanshan');
|
||||
insert into swtest.test_area values (21,'祁西县',13, 'Qixi');
|
||||
insert into swtest.test_area values (13,'衡阳市',2 , 'Hengyang');
|
||||
insert into swtest.test_area values (14,'耒阳市',13, 'Leiyang');
|
||||
insert into swtest.test_area values (15,'龙岗区',10, 'Longgang');
|
||||
insert into swtest.test_area values (16,'福田区',10, 'Futian');
|
||||
insert into swtest.test_area values (17,'宝安区',10, 'Baoan');
|
||||
insert into swtest.test_area values (19,'祁东县',13, 'Qidong');
|
||||
insert into swtest.test_area values (18,'常宁市',13, 'Changning');
|
||||
insert into swtest.test_area values (20,'祁南县',13, 'Qinan');
|
||||
create table swtest.test_area2(id int4, id2 text, name text, fatherid int4, fatherid2 text, name_desc text);
|
||||
insert into swtest.test_area2 values (1, 'A', '中国', 0, '', 'China');
|
||||
insert into swtest.test_area2 values (2, 'B', '湖南省',1 , 'A', 'Hunan');
|
||||
insert into swtest.test_area2 values (3, 'C', '广东省',1 , 'A', 'Guangdong');
|
||||
insert into swtest.test_area2 values (4, 'D', '海南省',1 , 'A', 'Hainan');
|
||||
insert into swtest.test_area2 values (5, 'E', '河北省',1 , 'A', 'Hebei');
|
||||
insert into swtest.test_area2 values (6, 'F', '河南省',1 , 'A', 'Henan');
|
||||
insert into swtest.test_area2 values (7, 'G', '山东省',1 , 'A', 'Shandong');
|
||||
insert into swtest.test_area2 values (8, 'H', '湖北省',1 , 'A', 'Hubei');
|
||||
insert into swtest.test_area2 values (9, 'I', '江苏省',1 , 'A', 'Jiangsu');
|
||||
insert into swtest.test_area2 values (10, 'J', '深圳市',3 , 'C', 'Shenzhen');
|
||||
insert into swtest.test_area2 values (11, 'K', '长沙市',2 , 'B', 'Changsha');
|
||||
insert into swtest.test_area2 values (22, 'L', '祁北县',13, 'O', 'Qibei');
|
||||
insert into swtest.test_area2 values (12, 'M', '南山区',10, 'J', 'Nanshan');
|
||||
insert into swtest.test_area2 values (21, 'N', '祁西县',13, 'O', 'Qixi');
|
||||
insert into swtest.test_area2 values (13, 'O', '衡阳市',2 , 'B', 'Hengyang');
|
||||
insert into swtest.test_area2 values (14, 'P', '耒阳市',13, 'O', 'Leiyang');
|
||||
insert into swtest.test_area2 values (15, 'Q', '龙岗区',10, 'J', 'Longgang');
|
||||
insert into swtest.test_area2 values (16, 'R', '福田区',10, 'J', 'Futian');
|
||||
insert into swtest.test_area2 values (17, 'S', '宝安区',10, 'J', 'Baoan');
|
||||
insert into swtest.test_area2 values (19, 'T', '祁东县',13, 'O', 'Qidong');
|
||||
insert into swtest.test_area2 values (18, 'U', '常宁市',13, 'O', 'Changning');
|
||||
insert into swtest.test_area2 values (20, 'V', '祁南县',13, 'O', 'Qinan');
|
||||
create table swtest.t1(id int, pid int, name text);
|
||||
insert into swtest.t1 values(1, 0, '1');
|
||||
insert into swtest.t1 values(2, 1, '2');
|
||||
insert into swtest.t1 values(3, 0, '3');
|
||||
insert into swtest.t1 values(4, 1, '4');
|
||||
insert into swtest.t1 values(5, 2, '5');
|
||||
insert into swtest.t1 values(6, 3, '6');
|
||||
insert into swtest.t1 values(7, 4, '7');
|
||||
insert into swtest.t1 values(8, 4, '8');
|
||||
insert into swtest.t1 values(9, 7, '9');
|
||||
create table swtest.t2(id int, pid int, name text);
|
||||
insert into swtest.t2 values(1, 0, '1');
|
||||
insert into swtest.t2 values(2, 1, '2');
|
||||
insert into swtest.t2 values(3, 0, '3');
|
||||
insert into swtest.t2 values(4, 1, '4');
|
||||
insert into swtest.t2 values(5, 2, '5');
|
||||
insert into swtest.t2 values(6, 3, '6');
|
||||
insert into swtest.t2 values(7, 4, '7');
|
||||
insert into swtest.t2 values(8, 4, '8');
|
||||
insert into swtest.t2 values(9, 7, '9');
|
||||
CREATE TABLE swtest.test_hcb_ptb(ID INT,CHA CHAR(10),VCH VARCHAR2(10),TEX TEXT,DAT DATE,TIM TIME,TIS TIMESTAMP,NAME VARCHAR2(80),PID INT,PCHA CHAR(10),PVCH VARCHAR2(10),PTEX TEXT,PDAT DATE,PTIM TIME,PTIS TIMESTAMP);
|
||||
CREATE TABLE swtest.TEST_HCB_FQB(ID INT,CHA CHAR(10),VCH VARCHAR2(10),TEX TEXT,DAT DATE,TIM TIME,TIS TIMESTAMP,NAME VARCHAR2(80),PID INT,PCHA CHAR(10),PVCH VARCHAR2(10),PTEX TEXT,PDAT DATE,PTIM TIME,PTIS TIMESTAMP);
|
||||
CREATE TABLE swtest.TEST_SUBLINK(ID INT,VCH VARCHAR2(10));
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 1 , 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12' ,'中国' , 0, '0' , '0' , '0' , '2000-12-12 12:12:12', '00:00:01', '2000-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 11 , 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01' ,'江苏省', 1, 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 12 , 'ab' , 'ab' , 'ab' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01' ,'山东省', 1, 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 13 , 'ac' , 'ac' , 'ac' , '2021-01-01 01:01:02', '01:01:02', '2021-01-01 01:01:02' ,'安徽省', 1, 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 14 , 'ad' , 'ad' , 'ad' , '2021-01-01 01:01:03', '01:01:03', '2021-01-01 01:01:03' ,'河南省', 1, 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 15 , 'ae' , 'ae' , 'ae' , '2021-01-01 01:01:05', '01:01:05', '2021-01-01 01:01:05' ,'河北省', 1, 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 16 , 'af' , 'af' , 'af' , '2021-01-01 01:01:06', '01:01:06', '2021-01-01 01:01:06' ,'湖南省', 1, 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 17 , 'ag' , 'ag' , 'ag' , '2021-01-01 01:01:07', '01:01:07', '2021-01-01 01:01:07' ,'湖北省', 1, 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 18 , 'ah' , 'ah' , 'ah' , '2021-01-01 01:01:08', '01:01:08', '2021-01-01 01:01:08' ,'贵州省', 1, 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 19 , 'ai' , 'ai' , 'ai' , '2021-01-01 01:01:09', '01:01:09', '2021-01-01 01:01:09' ,'武汉省', 1, 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(111 , 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10' ,'南京市', 11, 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(112 , 'aab', 'aab', 'aab', '2021-01-01 01:01:11', '01:01:11', '2021-01-01 01:01:11' ,'宿迁市', 11, 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(113 , 'aac', 'aac', 'aac', '2021-01-01 01:01:12', '01:01:12', '2021-01-01 01:01:12' ,'徐州市', 11, 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(114 , 'aad', 'aad', 'aad', '2021-01-01 01:01:13', '01:01:13', '2021-01-01 01:01:13' ,'苏州市', 11, 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(115 , 'aae', 'aae', 'aae', '2021-01-01 01:01:14', '01:01:14', '2021-01-01 01:01:14' ,'盐城市', 11, 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(116 , 'aaf', 'aaf', 'aaf', '2021-01-01 01:01:15', '01:01:15', '2021-01-01 01:01:15' ,'无锡市', 11, 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(117 , 'aag', 'aag', 'aag', '2021-01-01 01:01:16', '01:01:16', '2021-01-01 01:01:16' ,'常州市', 11, 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(118 , 'aah', 'aah', 'aah', '2021-01-01 01:01:17', '01:01:17', '2021-01-01 01:01:17' ,'连云港', 11, 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(119 , 'aai', 'aai', 'aai', '2021-01-01 01:01:18', '01:01:18', '2021-01-01 01:01:18' ,'泰州市', 11, 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(121 , 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20' ,'江宁区', 111, 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(122 , 'abb', 'abb', 'abb', '2021-01-01 01:01:21', '01:01:21', '2021-01-01 01:01:21' ,'雨花台', 111, 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(123 , 'abc', 'abc', 'abc', '2021-01-01 01:01:22', '01:01:22', '2021-01-01 01:01:22' ,'鼓楼区', 111, 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(124 , 'abd', 'abd', 'abd', '2021-01-01 01:01:23', '01:01:23', '2021-01-01 01:01:23' ,'玄武区', 111, 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(125 , 'abe', 'abe', 'abe', '2021-01-01 01:01:24', '01:01:24', '2021-01-01 01:01:24' ,'建邺区', 111, 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(126 , 'abf', 'abf', 'abf', '2021-01-01 01:01:25', '01:01:25', '2021-01-01 01:01:25' ,'秦淮区', 111, 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(127 , 'abg', 'abg', 'abg', '2021-01-01 01:01:26', '01:01:26', '2021-01-01 01:01:26' ,'浦口区', 111, 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(128 , 'abh', 'abh', 'abh', '2021-01-01 01:01:27', '01:01:27', '2021-01-01 01:01:27' ,'浦口区', 111, 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(129 , 'abi', 'abi', 'abi', '2021-01-01 01:01:28', '01:01:28', '2021-01-01 01:01:28' ,'六合区', 111, 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(131 , 'aca', 'aca', 'aca', '2021-01-01 01:01:30', '01:01:30', '2021-01-01 01:01:30' ,'东山街', 121, 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(132 , 'acb', 'acb', 'acb', '2021-01-01 01:01:31', '01:01:31', '2021-01-01 01:01:31' ,'秣陵街', 121, 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(133 , 'acc', 'acc', 'acc', '2021-01-01 01:01:32', '01:01:32', '2021-01-01 01:01:32' ,'汤山街', 121, 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(134 , 'acd', 'acd', 'acd', '2021-01-01 01:01:33', '01:01:33', '2021-01-01 01:01:33' ,'淳化街', 121, 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(135 , 'ace', 'ace', 'ace', '2021-01-01 01:01:34', '01:01:34', '2021-01-01 01:01:34' ,'禄口街', 121, 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(136 , 'acf', 'acf', 'acf', '2021-01-01 01:01:35', '01:01:35', '2021-01-01 01:01:35' ,'江宁街', 121, 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(137 , 'acg', 'acg', 'acg', '2021-01-01 01:01:36', '01:01:36', '2021-01-01 01:01:36' ,'谷里街', 121, 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(138 , 'ach', 'ach', 'ach', '2021-01-01 01:01:37', '01:01:37', '2021-01-01 01:01:37' ,'湖熟街', 121, 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(139 , 'aci', 'aci', 'aci', '2021-01-01 01:01:38', '01:01:38', '2021-01-01 01:01:38' ,'横溪街', 121, 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20');
|
||||
insert into swtest.test_hcb_ptb values( 1,'a',' a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12','中国', 0,'0','0','0','2000-12-12 12:12:12','00:00:01','2000-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values( 11,'aa',' aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01','江苏省', 1,'a','a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values( 12,'ab',' ab','ab','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01','山东省', 1,'a','a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values( 13,'ac',' ac','ac','2021-01-01 01:01:02','01:01:02','2021-01-01 01:01:02','安徽省', 1,'a','a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values( 14,'ad',' ad','ad','2021-01-01 01:01:03','01:01:03','2021-01-01 01:01:03','河南省', 1,'a','a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values( 15,'ae',' ae','ae','2021-01-01 01:01:05','01:01:05','2021-01-01 01:01:05','河北省', 1,'a','a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values( 16,'af',' af','af','2021-01-01 01:01:06','01:01:06','2021-01-01 01:01:06','湖南省', 1,'a','a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values( 17,'ag',' ag','ag','2021-01-01 01:01:07','01:01:07','2021-01-01 01:01:07','湖北省', 1,'a','a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values( 18,'ah',' ah','ah','2021-01-01 01:01:08','01:01:08','2021-01-01 01:01:08','贵州省', 1,'a','a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values( 19,'ai',' ai','ai','2021-01-01 01:01:09','01:01:09','2021-01-01 01:01:09','武汉省', 1,'a','a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values(111,'aaa',' aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10','南京市', 11,'aa','aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01' );
|
||||
insert into swtest.test_hcb_ptb values(112,'aab',' aab','aab','2021-01-01 01:01:11','01:01:11','2021-01-01 01:01:11','宿迁市', 11,'aa','aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01' );
|
||||
insert into swtest.test_hcb_ptb values(113,'aac',' aac','aac','2021-01-01 01:01:12','01:01:12','2021-01-01 01:01:12','徐州市', 11,'aa','aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01' );
|
||||
insert into swtest.test_hcb_ptb values(114,'aad',' aad','aad','2021-01-01 01:01:13','01:01:13','2021-01-01 01:01:13','苏州市', 11,'aa','aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01' );
|
||||
insert into swtest.test_hcb_ptb values(115,'aae',' aae','aae','2021-01-01 01:01:14','01:01:14','2021-01-01 01:01:14','盐城市', 11,'aa','aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01' );
|
||||
insert into swtest.test_hcb_ptb values(117,'aag',' aag','aag','2021-01-01 01:01:16','01:01:16','2021-01-01 01:01:16','常州市', 11,'aa','aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01' );
|
||||
insert into swtest.test_hcb_ptb values(116,'aaf',' aaf','aaf','2021-01-01 01:01:15','01:01:15','2021-01-01 01:01:15','无锡市', 11,'aa','aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01' );
|
||||
insert into swtest.test_hcb_ptb values(118,'aah',' aah','aah','2021-01-01 01:01:17','01:01:17','2021-01-01 01:01:17','连云港', 11,'aa','aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01' );
|
||||
insert into swtest.test_hcb_ptb values(119,'aai',' aai','aai','2021-01-01 01:01:18','01:01:18','2021-01-01 01:01:18','泰州市', 11,'aa','aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01' );
|
||||
insert into swtest.test_hcb_ptb values(121,'aba',' aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20','江宁区', 111,'aaa','aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10' );
|
||||
insert into swtest.test_hcb_ptb values(122,'abb',' abb','abb','2021-01-01 01:01:21','01:01:21','2021-01-01 01:01:21','雨花台', 111,'aaa','aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10' );
|
||||
insert into swtest.test_hcb_ptb values(123,'abc',' abc','abc','2021-01-01 01:01:22','01:01:22','2021-01-01 01:01:22','鼓楼区', 111,'aaa','aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10' );
|
||||
insert into swtest.test_hcb_ptb values(124,'abd',' abd','abd','2021-01-01 01:01:23','01:01:23','2021-01-01 01:01:23','玄武区', 111,'aaa','aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10' );
|
||||
insert into swtest.test_hcb_ptb values(125,'abe',' abe','abe','2021-01-01 01:01:24','01:01:24','2021-01-01 01:01:24','建邺区', 111,'aaa','aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10' );
|
||||
insert into swtest.test_hcb_ptb values(126,'abf',' abf','abf','2021-01-01 01:01:25','01:01:25','2021-01-01 01:01:25','秦淮区', 111,'aaa','aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10' );
|
||||
insert into swtest.test_hcb_ptb values(127,'abg',' abg','abg','2021-01-01 01:01:26','01:01:26','2021-01-01 01:01:26','浦口区', 111,'aaa','aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10' );
|
||||
insert into swtest.test_hcb_ptb values(128,'abh',' abh','abh','2021-01-01 01:01:27','01:01:27','2021-01-01 01:01:27','浦口区', 111,'aaa','aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10' );
|
||||
insert into swtest.test_hcb_ptb values(129,'abi',' abi','abi','2021-01-01 01:01:28','01:01:28','2021-01-01 01:01:28','六合区', 111,'aaa','aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10' );
|
||||
insert into swtest.test_hcb_ptb values(131,'aca',' aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30','东山街', 121,'aba','aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20' );
|
||||
insert into swtest.test_hcb_ptb values(132,'acb',' acb','acb','2021-01-01 01:01:31','01:01:31','2021-01-01 01:01:31','秣陵街', 121,'aba','aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20' );
|
||||
insert into swtest.test_hcb_ptb values(133,'acc',' acc','acc','2021-01-01 01:01:32','01:01:32','2021-01-01 01:01:32','汤山街', 121,'aba','aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20' );
|
||||
insert into swtest.test_hcb_ptb values(135,'ace',' ace','ace','2021-01-01 01:01:34','01:01:34','2021-01-01 01:01:34','禄口街', 121,'aba','aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20' );
|
||||
insert into swtest.test_hcb_ptb values(134,'acd',' acd','acd','2021-01-01 01:01:33','01:01:33','2021-01-01 01:01:33','淳化街', 121,'aba','aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20' );
|
||||
insert into swtest.test_hcb_ptb values(136,'acf',' acf','acf','2021-01-01 01:01:35','01:01:35','2021-01-01 01:01:35','江宁街', 121,'aba','aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20' );
|
||||
insert into swtest.test_hcb_ptb values(137,'acg',' acg','acg','2021-01-01 01:01:36','01:01:36','2021-01-01 01:01:36','谷里街', 121,'aba','aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20' );
|
||||
insert into swtest.test_hcb_ptb values(138,'ach',' ach','ach','2021-01-01 01:01:37','01:01:37','2021-01-01 01:01:37','湖熟街', 121,'aba','aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20' );
|
||||
insert into swtest.test_hcb_ptb values(139,'aci',' aci','aci','2021-01-01 01:01:38','01:01:38','2021-01-01 01:01:38','横溪街', 121,'aba','aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20' );
|
||||
insert into swtest.test_hcb_ptb values(141,'ada',' ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40','江南摩卡', 131,'aca','aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30' );
|
||||
insert into swtest.test_hcb_ptb values(142,'adb',' adb','adb','2021-01-01 01:01:41','01:01:41','2021-01-01 01:01:41','四季云顶', 131,'aca','aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30' );
|
||||
insert into swtest.test_hcb_ptb values(143,'adc',' adc','adc','2021-01-01 01:01:42','01:01:42','2021-01-01 01:01:42','盛世江南', 131,'aca','aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30' );
|
||||
insert into swtest.test_hcb_ptb values(144,'add',' add','add','2021-01-01 01:01:43','01:01:43','2021-01-01 01:01:43','七里香都', 131,'aca','aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30' );
|
||||
insert into swtest.test_hcb_ptb values(145,'ade',' ade','ade','2021-01-01 01:01:44','01:01:44','2021-01-01 01:01:44','西山枫林', 131,'aca','aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30' );
|
||||
insert into swtest.test_hcb_ptb values(146,'adf',' adf','adf','2021-01-01 01:01:45','01:01:45','2021-01-01 01:01:45','醉墨小镇', 131,'aca','aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30' );
|
||||
insert into swtest.test_hcb_ptb values(147,'adg',' adg','adg','2021-01-01 01:01:46','01:01:46','2021-01-01 01:01:46','布拉格调', 131,'aca','aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30' );
|
||||
insert into swtest.test_hcb_ptb values(148,'adh',' adh','adh','2021-01-01 01:01:47','01:01:47','2021-01-01 01:01:47','清幽别院', 131,'aca','aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30' );
|
||||
insert into swtest.test_hcb_ptb values(149,'adi',' adi','adi','2021-01-01 01:01:48','01:01:48','2021-01-01 01:01:48','璀璨天城', 131,'aca','aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30' );
|
||||
insert into swtest.test_hcb_ptb values(151,'aea',' aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50','江南一楼', 141,'ada','ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40' );
|
||||
insert into swtest.test_hcb_ptb values(152,'aeb',' aeb','aeb','2021-01-01 01:01:51','01:01:51','2021-01-01 01:01:51','江南二楼', 141,'ada','ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40' );
|
||||
insert into swtest.test_hcb_ptb values(153,'aec',' aec','aec','2021-01-01 01:01:52','01:01:52','2021-01-01 01:01:52','江南三楼', 141,'ada','ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40' );
|
||||
insert into swtest.test_hcb_ptb values(154,'aed',' aed','aed','2021-01-01 01:01:53','01:01:53','2021-01-01 01:01:53','江南四楼', 141,'ada','ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40' );
|
||||
insert into swtest.test_hcb_ptb values(155,'aee',' aee','aee','2021-01-01 01:01:54','01:01:54','2021-01-01 01:01:54','江南五楼', 141,'ada','ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40' );
|
||||
insert into swtest.test_hcb_ptb values(156,'aef',' aef','aef','2021-01-01 01:01:55','01:01:55','2021-01-01 01:01:55','江南六楼', 141,'ada','ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40' );
|
||||
insert into swtest.test_hcb_ptb values(157,'aeg',' aeg','aeg','2021-01-01 01:01:56','01:01:56','2021-01-01 01:01:56','江南七楼', 141,'ada','ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40' );
|
||||
insert into swtest.test_hcb_ptb values(158,'aeh',' aeh','aeh','2021-01-01 01:01:57','01:01:57','2021-01-01 01:01:57','江南八楼', 141,'ada','ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40' );
|
||||
insert into swtest.test_hcb_ptb values(159,'aei',' aei','aei','2021-01-01 01:01:58','01:01:58','2021-01-01 01:01:58','江南九楼', 141,'ada','ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40' );
|
||||
insert into swtest.test_hcb_ptb values(161,'afa',' afa','afa','2021-01-01 01:02:50','01:02:50','2021-01-01 01:02:50','第一单元', 151,'aea','aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50' );
|
||||
insert into swtest.test_hcb_ptb values(162,'afb',' afb','afb','2021-01-01 01:02:51','01:02:51','2021-01-01 01:02:51','第二单元', 151,'aea','aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50' );
|
||||
insert into swtest.test_hcb_ptb values(163,'afc',' afc','afc','2021-01-01 01:02:52','01:02:52','2021-01-01 01:02:52','第三单元', 151,'aea','aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50' );
|
||||
insert into swtest.test_hcb_ptb values(164,'afd',' afd','afd','2021-01-01 01:02:53','01:02:53','2021-01-01 01:02:53','第四单元', 151,'aea','aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50' );
|
||||
insert into swtest.test_hcb_ptb values(165,'afe',' afe','afe','2021-01-01 01:02:54','01:02:54','2021-01-01 01:02:54','第五单元', 151,'aea','aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50' );
|
||||
insert into swtest.test_hcb_ptb values(166,'aff',' aff','aff','2021-01-01 01:02:55','01:02:55','2021-01-01 01:02:55','第六单元', 151,'aea','aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50' );
|
||||
insert into swtest.test_hcb_ptb values(167,'afg',' afg','afg','2021-01-01 01:02:56','01:02:56','2021-01-01 01:02:56','第七单元', 151,'aea','aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50' );
|
||||
insert into swtest.test_hcb_ptb values(168,'afh',' afh','afh','2021-01-01 01:02:57','01:02:57','2021-01-01 01:02:57','第八单元', 151,'aea','aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50' );
|
||||
insert into swtest.test_hcb_ptb values(169,'afi',' afi','afi','2021-01-01 01:02:58','01:02:58','2021-01-01 01:02:58','第九单元', 151,'aea','aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50' );
|
||||
CREATE TABLE swtest.test_hcb_ptbc(ID INT,CHA CHAR(10),VCH VARCHAR2(10),TEX TEXT,DAT DATE,TIM TIME,TIS TIMESTAMP,NAME VARCHAR2(80),PID INT,PCHA CHAR(10),PVCH VARCHAR2(10),PTEX TEXT,PDAT DATE,PTIM TIME,PTIS TIMESTAMP
|
||||
) with (orientation = column);
|
||||
insert into test_hcb_ptbc select * from test_hcb_ptb;
|
||||
CREATE TABLE swtest.test_swcb_a (ID varchar2(10) PRIMARY KEY,NAME varchar2(100),PID varchar2(10));
|
||||
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "test_swcb_a_pkey" for table "test_swcb_a"
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00001', '中国', '-1');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00011', '陕西', '00001');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00012', '贵州', '00001');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00013', '河南', '00001');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00111', '西安', '00011');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00112', '咸阳', '00011');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00113', '延安', '00011');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00114', '华县', '00013');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00115', '河内', '00016');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00116', '清迈', '00015');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00117', '仰光', '00017');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00118', '纽约', '00120');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00119', '费城', '00118');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00120', '华盛顿', '00119');
|
||||
create table swtest.trait_value(TRAIT_VALUE_CD VARCHAR(50)primary key, TRAIT_VALUE_DESC VARCHAR(250) NULL, TRAIT_VAL VARCHAR(100) NULL, UOM_CD VARCHAR(50) NULL, TRAIT_CD VARCHAR(50) NULL,c1 serial);
|
||||
NOTICE: CREATE TABLE will create implicit sequence "trait_value_c1_seq" for serial column "trait_value.c1"
|
||||
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "trait_value_pkey" for table "trait_value"
|
||||
INSERT INTO swtest.TRAIT_VALUE VALUES ('A', NULL, 'A' , 'A' , 'A');
|
||||
INSERT INTO swtest.TRAIT_VALUE VALUES ('B', 'B' , NULL, 'B' , 'B');
|
||||
INSERT INTO swtest.TRAIT_VALUE VALUES ('C', 'C' , 'C' , NULL, NULL);
|
||||
INSERT INTO swtest.TRAIT_VALUE VALUES ('D', NULL, NULL, NULL, 'D');
|
||||
INSERT INTO swtest.TRAIT_VALUE VALUES ('E', 'E' , ' AA' , 'E' , 'E');
|
||||
INSERT INTO swtest.TRAIT_VALUE VALUES ('F', ' ' , 'AA ' , 'F' , 'F');
|
||||
create table swtest.offers_20050701(PROMO_ID VARCHAR(10), PARTY_ID VARCHAR(10) NULL, LOCATION_ID number(17,0) NULL);
|
||||
create table swtest.brand(a int default 2, mfg varchar(500), brand_cd varchar(500), brand_name varchar(100), brand_party_id number(18,10) NULL);
|
||||
analyze;
|
||||
498
src/test/regress/expected/sw_siblings.out
Normal file
498
src/test/regress/expected/sw_siblings.out
Normal file
@ -0,0 +1,498 @@
|
||||
set client_min_messages = error;
|
||||
set search_path=swtest;
|
||||
SET CLIENT_ENCODING='UTF8';
|
||||
/*
|
||||
*
|
||||
* START WITH .... CONNECT BY基础测试用例
|
||||
*
|
||||
* 测试用例表数
|
||||
* openGauss=# select * from swtest.test_area;
|
||||
* id | name | fatherid | name_desc
|
||||
* ----+--------+----------+-----------
|
||||
* 1 | 中国 | 0 | china
|
||||
* 2 | 湖南省 | 1 | hunan
|
||||
* 3 | 广东省 | 1 | guangdong
|
||||
* 4 | 海南省 | 1 | hainan
|
||||
* 5 | 河北省 | 1 | hebei
|
||||
* 6 | 河南省 | 1 | henan
|
||||
* 7 | 山东省 | 1 | shandong
|
||||
* 8 | 湖北省 | 1 | hubei
|
||||
* 9 | 江苏省 | 1 | jiangsu
|
||||
* 10 | 深圳市 | 3 | shenzhen
|
||||
* 11 | 长沙市 | 2 | changsha
|
||||
* 22 | 祁北县 | 13 | qibei
|
||||
* 12 | 南山区 | 10 | nanshan
|
||||
* 21 | 祁西县 | 13 | qixi
|
||||
* 13 | 衡阳市 | 2 | hengyang
|
||||
* 14 | 耒阳市 | 13 | leiyang
|
||||
* 15 | 龙岗区 | 10 | longgang
|
||||
* 16 | 福田区 | 10 | futian
|
||||
* 17 | 宝安区 | 10 | baoan
|
||||
* 19 | 祁东县 | 13 | qidong
|
||||
* 18 | 常宁市 | 13 | changning
|
||||
* 20 | 祁南县 | 13 | qinan
|
||||
*
|
||||
*/
|
||||
/* case 1.1 test root->leaf order siblings by id asc
|
||||
* expect order: 1 2 11 13 14 18 19 20 21 22 3 10 12 15 16 17 4 5 6 7 8 9
|
||||
*/
|
||||
EXPLAIN (costs off)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1, array_col_2, array_col_4, array_siblings
|
||||
-> Sort
|
||||
Sort Key: array_siblings
|
||||
-> Recursive Union
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id
|
||||
-> Seq Scan on test_area
|
||||
Filter: (name = '中国'::text)
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.fatherid = tmp_reuslt."test_area@id")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(18 rows)
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id;
|
||||
id | name | fatherid | name_desc | level | connect_by_isleaf | connect_by_iscycle | connect_by_root | cpath
|
||||
----+--------+----------+-----------+-------+-------------------+--------------------+-----------------+----------------------------
|
||||
1 | 中国 | 0 | China | 1 | 0 | 0 | China | @中国
|
||||
2 | 湖南省 | 1 | Hunan | 2 | 0 | 0 | China | @中国@湖南省
|
||||
11 | 长沙市 | 2 | Changsha | 3 | 1 | 0 | China | @中国@湖南省@长沙市
|
||||
13 | 衡阳市 | 2 | Hengyang | 3 | 0 | 0 | China | @中国@湖南省@衡阳市
|
||||
14 | 耒阳市 | 13 | Leiyang | 4 | 1 | 0 | China | @中国@湖南省@衡阳市@耒阳市
|
||||
18 | 常宁市 | 13 | Changning | 4 | 1 | 0 | China | @中国@湖南省@衡阳市@常宁市
|
||||
19 | 祁东县 | 13 | Qidong | 4 | 1 | 0 | China | @中国@湖南省@衡阳市@祁东县
|
||||
20 | 祁南县 | 13 | Qinan | 4 | 1 | 0 | China | @中国@湖南省@衡阳市@祁南县
|
||||
21 | 祁西县 | 13 | Qixi | 4 | 1 | 0 | China | @中国@湖南省@衡阳市@祁西县
|
||||
22 | 祁北县 | 13 | Qibei | 4 | 1 | 0 | China | @中国@湖南省@衡阳市@祁北县
|
||||
3 | 广东省 | 1 | Guangdong | 2 | 0 | 0 | China | @中国@广东省
|
||||
10 | 深圳市 | 3 | Shenzhen | 3 | 0 | 0 | China | @中国@广东省@深圳市
|
||||
12 | 南山区 | 10 | Nanshan | 4 | 1 | 0 | China | @中国@广东省@深圳市@南山区
|
||||
15 | 龙岗区 | 10 | Longgang | 4 | 1 | 0 | China | @中国@广东省@深圳市@龙岗区
|
||||
16 | 福田区 | 10 | Futian | 4 | 1 | 0 | China | @中国@广东省@深圳市@福田区
|
||||
17 | 宝安区 | 10 | Baoan | 4 | 1 | 0 | China | @中国@广东省@深圳市@宝安区
|
||||
4 | 海南省 | 1 | Hainan | 2 | 1 | 0 | China | @中国@海南省
|
||||
5 | 河北省 | 1 | Hebei | 2 | 1 | 0 | China | @中国@河北省
|
||||
6 | 河南省 | 1 | Henan | 2 | 1 | 0 | China | @中国@河南省
|
||||
7 | 山东省 | 1 | Shandong | 2 | 1 | 0 | China | @中国@山东省
|
||||
8 | 湖北省 | 1 | Hubei | 2 | 1 | 0 | China | @中国@湖北省
|
||||
9 | 江苏省 | 1 | Jiangsu | 2 | 1 | 0 | China | @中国@江苏省
|
||||
(22 rows)
|
||||
|
||||
/* case 1.2 test root->leaf order siblings by id desc
|
||||
* expect order: 1 9 8 7 6 5 4 3 10 17 16 15 12 2 13 22 21 20 19 18 14 11
|
||||
*/
|
||||
EXPLAIN (costs off)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id desc;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1, array_col_2, array_col_4, array_siblings
|
||||
-> Sort
|
||||
Sort Key: array_siblings
|
||||
-> Recursive Union
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id DESC
|
||||
-> Seq Scan on test_area
|
||||
Filter: (name = '中国'::text)
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id DESC
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.fatherid = tmp_reuslt."test_area@id")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(18 rows)
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id desc;
|
||||
id | name | fatherid | name_desc | level | connect_by_isleaf | connect_by_iscycle | connect_by_root | cpath
|
||||
----+--------+----------+-----------+-------+-------------------+--------------------+-----------------+----------------------------
|
||||
1 | 中国 | 0 | China | 1 | 0 | 0 | China | @中国
|
||||
9 | 江苏省 | 1 | Jiangsu | 2 | 1 | 0 | China | @中国@江苏省
|
||||
8 | 湖北省 | 1 | Hubei | 2 | 1 | 0 | China | @中国@湖北省
|
||||
7 | 山东省 | 1 | Shandong | 2 | 1 | 0 | China | @中国@山东省
|
||||
6 | 河南省 | 1 | Henan | 2 | 1 | 0 | China | @中国@河南省
|
||||
5 | 河北省 | 1 | Hebei | 2 | 1 | 0 | China | @中国@河北省
|
||||
4 | 海南省 | 1 | Hainan | 2 | 1 | 0 | China | @中国@海南省
|
||||
3 | 广东省 | 1 | Guangdong | 2 | 0 | 0 | China | @中国@广东省
|
||||
10 | 深圳市 | 3 | Shenzhen | 3 | 0 | 0 | China | @中国@广东省@深圳市
|
||||
17 | 宝安区 | 10 | Baoan | 4 | 1 | 0 | China | @中国@广东省@深圳市@宝安区
|
||||
16 | 福田区 | 10 | Futian | 4 | 1 | 0 | China | @中国@广东省@深圳市@福田区
|
||||
15 | 龙岗区 | 10 | Longgang | 4 | 1 | 0 | China | @中国@广东省@深圳市@龙岗区
|
||||
12 | 南山区 | 10 | Nanshan | 4 | 1 | 0 | China | @中国@广东省@深圳市@南山区
|
||||
2 | 湖南省 | 1 | Hunan | 2 | 0 | 0 | China | @中国@湖南省
|
||||
13 | 衡阳市 | 2 | Hengyang | 3 | 0 | 0 | China | @中国@湖南省@衡阳市
|
||||
22 | 祁北县 | 13 | Qibei | 4 | 1 | 0 | China | @中国@湖南省@衡阳市@祁北县
|
||||
21 | 祁西县 | 13 | Qixi | 4 | 1 | 0 | China | @中国@湖南省@衡阳市@祁西县
|
||||
20 | 祁南县 | 13 | Qinan | 4 | 1 | 0 | China | @中国@湖南省@衡阳市@祁南县
|
||||
19 | 祁东县 | 13 | Qidong | 4 | 1 | 0 | China | @中国@湖南省@衡阳市@祁东县
|
||||
18 | 常宁市 | 13 | Changning | 4 | 1 | 0 | China | @中国@湖南省@衡阳市@常宁市
|
||||
14 | 耒阳市 | 13 | Leiyang | 4 | 1 | 0 | China | @中国@湖南省@衡阳市@耒阳市
|
||||
11 | 长沙市 | 2 | Changsha | 3 | 1 | 0 | China | @中国@湖南省@长沙市
|
||||
(22 rows)
|
||||
|
||||
/* case 1.3 test double_root->leaf order siblings by id asc
|
||||
* expect order: 10 12 15 16 17 13 14 18 19 20 21 22
|
||||
*/
|
||||
EXPLAIN (costs off)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '衡阳市' or name = '深圳市'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1, array_col_2, array_col_4, array_siblings
|
||||
-> Sort
|
||||
Sort Key: array_siblings
|
||||
-> Recursive Union
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id
|
||||
-> Seq Scan on test_area
|
||||
Filter: ((name = '衡阳市'::text) OR (name = '深圳市'::text))
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.fatherid = tmp_reuslt."test_area@id")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(18 rows)
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '衡阳市' or name = '深圳市'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id;
|
||||
id | name | fatherid | name_desc | level | connect_by_isleaf | connect_by_iscycle | connect_by_root | cpath
|
||||
----+--------+----------+-----------+-------+-------------------+--------------------+-----------------+----------------
|
||||
10 | 深圳市 | 3 | Shenzhen | 1 | 0 | 0 | Shenzhen | @深圳市
|
||||
12 | 南山区 | 10 | Nanshan | 2 | 1 | 0 | Shenzhen | @深圳市@南山区
|
||||
15 | 龙岗区 | 10 | Longgang | 2 | 1 | 0 | Shenzhen | @深圳市@龙岗区
|
||||
16 | 福田区 | 10 | Futian | 2 | 1 | 0 | Shenzhen | @深圳市@福田区
|
||||
17 | 宝安区 | 10 | Baoan | 2 | 1 | 0 | Shenzhen | @深圳市@宝安区
|
||||
13 | 衡阳市 | 2 | Hengyang | 1 | 0 | 0 | Hengyang | @衡阳市
|
||||
14 | 耒阳市 | 13 | Leiyang | 2 | 1 | 0 | Hengyang | @衡阳市@耒阳市
|
||||
18 | 常宁市 | 13 | Changning | 2 | 1 | 0 | Hengyang | @衡阳市@常宁市
|
||||
19 | 祁东县 | 13 | Qidong | 2 | 1 | 0 | Hengyang | @衡阳市@祁东县
|
||||
20 | 祁南县 | 13 | Qinan | 2 | 1 | 0 | Hengyang | @衡阳市@祁南县
|
||||
21 | 祁西县 | 13 | Qixi | 2 | 1 | 0 | Hengyang | @衡阳市@祁西县
|
||||
22 | 祁北县 | 13 | Qibei | 2 | 1 | 0 | Hengyang | @衡阳市@祁北县
|
||||
(12 rows)
|
||||
|
||||
|
||||
/* case 1.4 test double_root->leaf order siblings by id desc
|
||||
* expect order: 13 22 21 20 19 18 14 10 17 16 15 12
|
||||
*/
|
||||
EXPLAIN (costs off)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '衡阳市' or name = '深圳市'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id desc;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1, array_col_2, array_col_4, array_siblings
|
||||
-> Sort
|
||||
Sort Key: array_siblings
|
||||
-> Recursive Union
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id DESC
|
||||
-> Seq Scan on test_area
|
||||
Filter: ((name = '衡阳市'::text) OR (name = '深圳市'::text))
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id DESC
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.fatherid = tmp_reuslt."test_area@id")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(18 rows)
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '衡阳市' or name = '深圳市'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id desc;
|
||||
id | name | fatherid | name_desc | level | connect_by_isleaf | connect_by_iscycle | connect_by_root | cpath
|
||||
----+--------+----------+-----------+-------+-------------------+--------------------+-----------------+----------------
|
||||
13 | 衡阳市 | 2 | Hengyang | 1 | 0 | 0 | Hengyang | @衡阳市
|
||||
22 | 祁北县 | 13 | Qibei | 2 | 1 | 0 | Hengyang | @衡阳市@祁北县
|
||||
21 | 祁西县 | 13 | Qixi | 2 | 1 | 0 | Hengyang | @衡阳市@祁西县
|
||||
20 | 祁南县 | 13 | Qinan | 2 | 1 | 0 | Hengyang | @衡阳市@祁南县
|
||||
19 | 祁东县 | 13 | Qidong | 2 | 1 | 0 | Hengyang | @衡阳市@祁东县
|
||||
18 | 常宁市 | 13 | Changning | 2 | 1 | 0 | Hengyang | @衡阳市@常宁市
|
||||
14 | 耒阳市 | 13 | Leiyang | 2 | 1 | 0 | Hengyang | @衡阳市@耒阳市
|
||||
10 | 深圳市 | 3 | Shenzhen | 1 | 0 | 0 | Shenzhen | @深圳市
|
||||
17 | 宝安区 | 10 | Baoan | 2 | 1 | 0 | Shenzhen | @深圳市@宝安区
|
||||
16 | 福田区 | 10 | Futian | 2 | 1 | 0 | Shenzhen | @深圳市@福田区
|
||||
15 | 龙岗区 | 10 | Longgang | 2 | 1 | 0 | Shenzhen | @深圳市@龙岗区
|
||||
12 | 南山区 | 10 | Nanshan | 2 | 1 | 0 | Shenzhen | @深圳市@南山区
|
||||
(12 rows)
|
||||
|
||||
|
||||
/* case 1.5 test leaf->root order siblings by id asc
|
||||
* expect order: 18 13 2 1
|
||||
*/
|
||||
EXPLAIN (costs off)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '常宁市'
|
||||
CONNECT BY id = prior fatherid
|
||||
ORDER SIBLINGS BY id;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_3, array_col_2, array_col_4, array_siblings
|
||||
-> Sort
|
||||
Sort Key: array_siblings
|
||||
-> Recursive Union
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id
|
||||
-> Seq Scan on test_area
|
||||
Filter: (name = '常宁市'::text)
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.id = tmp_reuslt."test_area@fatherid")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(18 rows)
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '常宁市'
|
||||
CONNECT BY id = prior fatherid
|
||||
ORDER SIBLINGS BY id;
|
||||
id | name | fatherid | name_desc | level | connect_by_isleaf | connect_by_iscycle | connect_by_root | cpath
|
||||
----+--------+----------+-----------+-------+-------------------+--------------------+-----------------+----------------------------
|
||||
18 | 常宁市 | 13 | Changning | 1 | 0 | 0 | Changning | @常宁市
|
||||
13 | 衡阳市 | 2 | Hengyang | 2 | 0 | 0 | Changning | @常宁市@衡阳市
|
||||
2 | 湖南省 | 1 | Hunan | 3 | 0 | 0 | Changning | @常宁市@衡阳市@湖南省
|
||||
1 | 中国 | 0 | China | 4 | 1 | 0 | Changning | @常宁市@衡阳市@湖南省@中国
|
||||
(4 rows)
|
||||
|
||||
/* case 1.6 test leaf->root order siblings by id desc
|
||||
* expect order: 18 13 2 1
|
||||
*/
|
||||
EXPLAIN (costs off)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '常宁市'
|
||||
CONNECT BY id = prior fatherid
|
||||
ORDER SIBLINGS BY id desc;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_3, array_col_2, array_col_4, array_siblings
|
||||
-> Sort
|
||||
Sort Key: array_siblings
|
||||
-> Recursive Union
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id DESC
|
||||
-> Seq Scan on test_area
|
||||
Filter: (name = '常宁市'::text)
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id DESC
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.id = tmp_reuslt."test_area@fatherid")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(18 rows)
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '常宁市'
|
||||
CONNECT BY id = prior fatherid
|
||||
ORDER SIBLINGS BY id desc;
|
||||
id | name | fatherid | name_desc | level | connect_by_isleaf | connect_by_iscycle | connect_by_root | cpath
|
||||
----+--------+----------+-----------+-------+-------------------+--------------------+-----------------+----------------------------
|
||||
18 | 常宁市 | 13 | Changning | 1 | 0 | 0 | Changning | @常宁市
|
||||
13 | 衡阳市 | 2 | Hengyang | 2 | 0 | 0 | Changning | @常宁市@衡阳市
|
||||
2 | 湖南省 | 1 | Hunan | 3 | 0 | 0 | Changning | @常宁市@衡阳市@湖南省
|
||||
1 | 中国 | 0 | China | 4 | 1 | 0 | Changning | @常宁市@衡阳市@湖南省@中国
|
||||
(4 rows)
|
||||
|
||||
/* case 1.7
|
||||
* test order siblings by const
|
||||
* expect order: 1 2 11 13 14 18 19 20 21 22 3 10 12 15 16 17 4 5 6 7 8 9
|
||||
*/
|
||||
EXPLAIN (costs off)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY 1;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1, array_col_2, array_col_4, array_siblings
|
||||
-> Sort
|
||||
Sort Key: array_siblings
|
||||
-> Recursive Union
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id
|
||||
-> Seq Scan on test_area
|
||||
Filter: (name = '中国'::text)
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.fatherid = tmp_reuslt."test_area@id")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(18 rows)
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY 1;
|
||||
id | name | fatherid | name_desc | level | connect_by_isleaf | connect_by_iscycle | connect_by_root | cpath
|
||||
----+--------+----------+-----------+-------+-------------------+--------------------+-----------------+----------------------------
|
||||
1 | 中国 | 0 | China | 1 | 0 | 0 | China | @中国
|
||||
2 | 湖南省 | 1 | Hunan | 2 | 0 | 0 | China | @中国@湖南省
|
||||
11 | 长沙市 | 2 | Changsha | 3 | 1 | 0 | China | @中国@湖南省@长沙市
|
||||
13 | 衡阳市 | 2 | Hengyang | 3 | 0 | 0 | China | @中国@湖南省@衡阳市
|
||||
14 | 耒阳市 | 13 | Leiyang | 4 | 1 | 0 | China | @中国@湖南省@衡阳市@耒阳市
|
||||
18 | 常宁市 | 13 | Changning | 4 | 1 | 0 | China | @中国@湖南省@衡阳市@常宁市
|
||||
19 | 祁东县 | 13 | Qidong | 4 | 1 | 0 | China | @中国@湖南省@衡阳市@祁东县
|
||||
20 | 祁南县 | 13 | Qinan | 4 | 1 | 0 | China | @中国@湖南省@衡阳市@祁南县
|
||||
21 | 祁西县 | 13 | Qixi | 4 | 1 | 0 | China | @中国@湖南省@衡阳市@祁西县
|
||||
22 | 祁北县 | 13 | Qibei | 4 | 1 | 0 | China | @中国@湖南省@衡阳市@祁北县
|
||||
3 | 广东省 | 1 | Guangdong | 2 | 0 | 0 | China | @中国@广东省
|
||||
10 | 深圳市 | 3 | Shenzhen | 3 | 0 | 0 | China | @中国@广东省@深圳市
|
||||
12 | 南山区 | 10 | Nanshan | 4 | 1 | 0 | China | @中国@广东省@深圳市@南山区
|
||||
15 | 龙岗区 | 10 | Longgang | 4 | 1 | 0 | China | @中国@广东省@深圳市@龙岗区
|
||||
16 | 福田区 | 10 | Futian | 4 | 1 | 0 | China | @中国@广东省@深圳市@福田区
|
||||
17 | 宝安区 | 10 | Baoan | 4 | 1 | 0 | China | @中国@广东省@深圳市@宝安区
|
||||
4 | 海南省 | 1 | Hainan | 2 | 1 | 0 | China | @中国@海南省
|
||||
5 | 河北省 | 1 | Hebei | 2 | 1 | 0 | China | @中国@河北省
|
||||
6 | 河南省 | 1 | Henan | 2 | 1 | 0 | China | @中国@河南省
|
||||
7 | 山东省 | 1 | Shandong | 2 | 1 | 0 | China | @中国@山东省
|
||||
8 | 湖北省 | 1 | Hubei | 2 | 1 | 0 | China | @中国@湖北省
|
||||
9 | 江苏省 | 1 | Jiangsu | 2 | 1 | 0 | China | @中国@江苏省
|
||||
(22 rows)
|
||||
|
||||
/* case 1.8++ test explain for multiple order siblings column */
|
||||
EXPLAIN (costs off)
|
||||
SELECT * FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id, name, name_desc;
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1, array_siblings
|
||||
-> Sort
|
||||
Sort Key: array_siblings
|
||||
-> Recursive Union
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id, swtest.test_area.name, swtest.test_area.name_desc
|
||||
-> Seq Scan on test_area
|
||||
Filter: (name = '中国'::text)
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id, swtest.test_area.name, swtest.test_area.name_desc
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.fatherid = tmp_reuslt."test_area@id")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(18 rows)
|
||||
|
||||
EXPLAIN (costs off)
|
||||
SELECT * FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id desc, name desc , name_desc desc;
|
||||
QUERY PLAN
|
||||
-----------------------------------------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1, array_siblings
|
||||
-> Sort
|
||||
Sort Key: array_siblings
|
||||
-> Recursive Union
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id DESC, swtest.test_area.name DESC, swtest.test_area.name_desc DESC
|
||||
-> Seq Scan on test_area
|
||||
Filter: (name = '中国'::text)
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id DESC, swtest.test_area.name DESC, swtest.test_area.name_desc DESC
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.fatherid = tmp_reuslt."test_area@id")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(18 rows)
|
||||
|
||||
EXPLAIN (costs off)
|
||||
SELECT * FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id desc, name, name_desc desc;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------------------------
|
||||
CTE Scan on tmp_reuslt
|
||||
CTE tmp_reuslt
|
||||
-> StartWith Operator
|
||||
Start With pseudo atts: RUITR, array_key_1, array_siblings
|
||||
-> Sort
|
||||
Sort Key: array_siblings
|
||||
-> Recursive Union
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id DESC, swtest.test_area.name, swtest.test_area.name_desc DESC
|
||||
-> Seq Scan on test_area
|
||||
Filter: (name = '中国'::text)
|
||||
-> Sort
|
||||
Sort Key: swtest.test_area.id DESC, swtest.test_area.name, swtest.test_area.name_desc DESC
|
||||
-> Hash Join
|
||||
Hash Cond: (swtest.test_area.fatherid = tmp_reuslt."test_area@id")
|
||||
-> Seq Scan on test_area
|
||||
-> Hash
|
||||
-> WorkTable Scan on tmp_reuslt
|
||||
(18 rows)
|
||||
|
||||
@ -22,6 +22,11 @@ test: get_instr_unique_sql
|
||||
# interferes with crash-recovery testing.
|
||||
test: single_node_tablespace
|
||||
|
||||
#test startwith...connect by
|
||||
test: sw_prepare
|
||||
test: sw_basic sw_icbc sw_siblings sw_bugfix sw_by_rownum_level
|
||||
test: sw_clearup
|
||||
|
||||
# ----------
|
||||
# The first group of parallel tests
|
||||
# ----------
|
||||
|
||||
182
src/test/regress/sql/sw_basic.sql
Normal file
182
src/test/regress/sql/sw_basic.sql
Normal file
@ -0,0 +1,182 @@
|
||||
set client_min_messages = error;
|
||||
set search_path=swtest;
|
||||
SET CLIENT_ENCODING='UTF8';
|
||||
|
||||
/*
|
||||
*
|
||||
* START WITH .... CONNECT BY基础测试用例
|
||||
*
|
||||
* 测试用例表数
|
||||
* openGauss=# select * from swtest.test_area;
|
||||
* id | name | fatherid | name_desc
|
||||
* ----+--------+----------+-----------
|
||||
* 1 | 中国 | 0 | china
|
||||
* 2 | 湖南省 | 1 | hunan
|
||||
* 3 | 广东省 | 1 | guangdong
|
||||
* 4 | 海南省 | 1 | hainan
|
||||
* 5 | 河北省 | 1 | hebei
|
||||
* 6 | 河南省 | 1 | henan
|
||||
* 7 | 山东省 | 1 | shandong
|
||||
* 8 | 湖北省 | 1 | hubei
|
||||
* 9 | 江苏省 | 1 | jiangsu
|
||||
* 10 | 深圳市 | 3 | shenzhen
|
||||
* 11 | 长沙市 | 2 | changsha
|
||||
* 22 | 祁北县 | 13 | qibei
|
||||
* 12 | 南山区 | 10 | nanshan
|
||||
* 21 | 祁西县 | 13 | qixi
|
||||
* 13 | 衡阳市 | 2 | hengyang
|
||||
* 14 | 耒阳市 | 13 | leiyang
|
||||
* 15 | 龙岗区 | 10 | longgang
|
||||
* 16 | 福田区 | 10 | futian
|
||||
* 17 | 宝安区 | 10 | baoan
|
||||
* 19 | 祁东县 | 13 | qidong
|
||||
* 18 | 常宁市 | 13 | changning
|
||||
* 20 | 祁南县 | 13 | qinan
|
||||
*
|
||||
*/
|
||||
|
||||
-- 一、基础语法测试
|
||||
/*
|
||||
* 用例1.1,基础用例包含所有伪列,leaf节点方向遍历查找
|
||||
**/
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '@')
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '@')
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
|
||||
/*
|
||||
* 用例1.2,基础用例包含所有伪列,root节点方向遍历查找
|
||||
**/
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '@')
|
||||
FROM test_area
|
||||
START WITH name = '耒阳市'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '@')
|
||||
FROM test_area
|
||||
START WITH name = '耒阳市'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
|
||||
/*
|
||||
* 用例1.3,基础用例包含所有伪列,root节点方向遍历查找(两条链)
|
||||
**/
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '@')
|
||||
FROM test_area
|
||||
START WITH name = '耒阳市' OR name = '宝安区'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '@')
|
||||
FROM test_area
|
||||
START WITH name = '耒阳市' OR name = '宝安区'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
|
||||
/*
|
||||
* 用例1.5,基础用例包含所有伪列,测试多字符串拼接
|
||||
**/
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '=>>')
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '=>>')
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
|
||||
/*
|
||||
* 用例1.6,基础用例包含所有伪列, 包含多字符拼接,多条查找链,startwith使用LIKE查找
|
||||
**/
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '-*>')
|
||||
FROM test_area
|
||||
START WITH name like '%区'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '-*>')
|
||||
FROM test_area
|
||||
START WITH name like '%区'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
|
||||
-- 二、扩展测试
|
||||
/*
|
||||
* 用例2.1,基础用例包含所有伪列, 包含多字符拼接,多条查找链,startwith使用IN子查询进行查找
|
||||
**/
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '/')
|
||||
FROM test_area
|
||||
START WITH name IN (select name from test_area where id < 3)
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '/')
|
||||
FROM test_area
|
||||
START WITH name IN (select name from test_area where id < 3)
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
|
||||
/*
|
||||
* 用例2.2,基础用例包含所有伪列, 包含多字符拼接,多条查找链,startwith使用IN子查询进行查找,结果集进行伪列过滤
|
||||
**/
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '/')
|
||||
FROM test_area
|
||||
WHERE LEVEL > 2
|
||||
START WITH name IN (select name from test_area where id < 3)
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '/')
|
||||
FROM test_area
|
||||
WHERE LEVEL > 2
|
||||
START WITH name IN (select name from test_area where id < 3)
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
|
||||
/*
|
||||
* 用例2.3,基础用例包含所有伪列, 包含多字符拼接,多条查找链,startwith使用IN子查询进行查找,结果集进行多个伪列过滤
|
||||
**/
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '/')
|
||||
FROM test_area
|
||||
WHERE LEVEL > 2 AND connect_by_iscycle IS NOT NULL
|
||||
START WITH name IN (select name from test_area where id < 3)
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), sys_connect_by_path(name_desc, '/')
|
||||
FROM test_area
|
||||
WHERE LEVEL > 2 AND connect_by_iscycle IS NOT NULL
|
||||
START WITH name IN (select name from test_area where id < 3)
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
|
||||
-- 三、 打开guc enable_startwith_debug = on测试
|
||||
/* DFX test, verify if */
|
||||
set enable_startwith_debug=on;
|
||||
set client_min_messages=log;
|
||||
|
||||
explain (costs off)
|
||||
select *, LEVEL, CONNECT_BY_ROOT(name_desc), SYS_CONNECT_BY_PATH(name, '/') cpath from test_area
|
||||
START WITH name = '耒阳市'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
|
||||
select *, LEVEL, CONNECT_BY_ROOT(name_desc), SYS_CONNECT_BY_PATH(name, '/') cpath from test_area
|
||||
START WITH name = '耒阳市'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
|
||||
explain (costs off)
|
||||
select *, LEVEL, CONNECT_BY_ROOT(name_desc), SYS_CONNECT_BY_PATH(name, '/') cpath from test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
order siblings by id;
|
||||
|
||||
select *, LEVEL, CONNECT_BY_ROOT(name_desc), SYS_CONNECT_BY_PATH(name, '/') cpath from test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
order siblings by id;
|
||||
|
||||
reset enable_startwith_debug;
|
||||
reset client_min_messages;
|
||||
844
src/test/regress/sql/sw_bugfix.sql
Normal file
844
src/test/regress/sql/sw_bugfix.sql
Normal file
@ -0,0 +1,844 @@
|
||||
set client_min_messages = error;
|
||||
SET CLIENT_ENCODING='UTF8';
|
||||
set current_schema=swtest;
|
||||
|
||||
/* invalid data type */
|
||||
SELECT NAME,LEVEL,CONNECT_BY_ISLEAF,SYS_CONNECT_BY_PATH(NAME,'|'),CONNECT_BY_ROOT(NAME),ID,CHA,VCH,TEX,DAT,TIM,TIS,PID,PCHA,PVCH,PTEX,PDAT,PTIM,PTIS
|
||||
FROM TEST_HCB_FQB
|
||||
START WITH ID=1
|
||||
CONNECT BY prior ID=PID
|
||||
ORDER SIBLINGS BY NAME ASC;
|
||||
|
||||
-- invalid use connect_by_root, will treate it as regular column report column does not exists error
|
||||
SELECT NAME,LEVEL,CONNECT_BY_ISLEAF,SYS_CONNECT_BY_PATH(NAME,'|'),CONNECT_BY_ROOT
|
||||
FROM test_hcb_ptb
|
||||
START WITH (ID=169 or ID=168) and CHA in ('afi','afg','afh')
|
||||
CONNECT BY ID=PRIOR PID and CHA=PRIOR PCHA and VCH=PRIOR PVCH and DAT=PRIOR PDAT and TIM=PRIOR PTIM AND TIS=PRIOR PTIS
|
||||
order by 1;
|
||||
|
||||
SELECT NAME,LEVEL,CONNECT_BY_ISLEAF,SYS_CONNECT_BY_PATH(NAME,'|'),CONNECT_BY_ROOT name
|
||||
FROM test_hcb_ptb
|
||||
START WITH (ID=169 or ID=168) and CHA in ('afi','afg','afh')
|
||||
CONNECT BY ID=PRIOR PID and CHA=PRIOR PCHA and VCH=PRIOR PVCH and DAT=PRIOR PDAT and TIM=PRIOR PTIM AND TIS=PRIOR PTIS
|
||||
order by 1;
|
||||
|
||||
SELECT NAME,LEVEL,CONNECT_BY_ISLEAF,SYS_CONNECT_BY_PATH(NAME,'|'),CONNECT_BY_ROOT(name)
|
||||
FROM test_hcb_ptb
|
||||
START WITH (ID=169 or ID=168) and CHA in ('afi','afg','afh')
|
||||
CONNECT BY ID=PRIOR PID and CHA=PRIOR PCHA and VCH=PRIOR PVCH and DAT=PRIOR PDAT and TIM=PRIOR PTIM AND TIS=PRIOR PTIS
|
||||
order by 1;
|
||||
|
||||
/* Unsupported StartWith Scenarios */
|
||||
explain(costs off)
|
||||
select * from test_hcb_ptbc t1 start with t1.id = 11 connect by prior t1.id = t1.pid;
|
||||
select * from test_hcb_ptbc t1 start with t1.id = 11 connect by prior t1.id = t1.pid;
|
||||
SELECT t1.id,t1.pid,t1.name,level FROM test_hcb_ptb t1,test_hcb_ptb t2 WHERE t1.id=t2.id START WITH t1.id=141 CONNECT BY PRIOR t1.id=t1.pid FOR UPDATE OF t2 NOWAIT;
|
||||
SELECT t1.id, t1.pid,t1.name,level FROM core_066 t1 START WITH id = 117 CONNECT BY PRIOR id=pid FOR UPDATE;
|
||||
|
||||
/* connect by root scenarios */
|
||||
select pid x,id,CONNECT_BY_ROOT ID from test_hcb_ptbc t1 start with id = 11 connect by prior id = pid;
|
||||
select pid x,id,CONNECT_BY_ROOT ID alias_id from test_hcb_ptbc t1 start with id = 11 connect by prior id = pid;
|
||||
select pid x,id,CONNECT_BY_ROOT t1.ID from test_hcb_ptbc t1 start with id = 11 connect by prior id = pid;
|
||||
select pid x,id,CONNECT_BY_ROOT t1.ID alias_id from test_hcb_ptbc t1 start with id = 11 connect by prior id = pid;
|
||||
|
||||
/* infinite loop issues */
|
||||
SELECT LEVEL,NAME,CONNECT_BY_ISLEAF,SYS_CONNECT_BY_PATH(NAME, '/'),CONNECT_BY_ROOT(ID)
|
||||
FROM test_swcb_a
|
||||
START WITH ID='00118'
|
||||
CONNECT BY PRIOR ID=PID
|
||||
ORDER SIBLINGS BY NAME;
|
||||
|
||||
/* fromlist startwith for single table */
|
||||
select t1.ID,t1.VCH,pid,NAME,PTEX from TEST_HCB_FQB t1,TEST_SUBLINK t2 where t1.id=t2.id start with t1.id=1 CONNECT BY PRIOR t1.id = t1.pid;
|
||||
explain (costs off) select t1.ID,t1.VCH,pid,NAME,PTEX from TEST_HCB_FQB t1,TEST_SUBLINK t2 where t1.id=t2.id start with t1.id=1 CONNECT BY PRIOR t1.id = t1.pid;
|
||||
|
||||
/* swcb中参数为proceder参数 */
|
||||
CREATE OR REPLACE FUNCTION test_hcb_pro1(i_id in int) return int
|
||||
AS
|
||||
o_out int;
|
||||
BEGIN
|
||||
select count(*) into o_out from TEST_HCB_FQB t1 START WITH t1.id = i_id
|
||||
CONNECT BY PRIOR t1.id = t1.pid;
|
||||
return o_out;
|
||||
END;
|
||||
/
|
||||
|
||||
select test_hcb_pro1(11);
|
||||
drop PROCEDURE test_hcb_pro1;
|
||||
|
||||
/* startwith dealing with subqueries */
|
||||
select tt.id,tt.name from (select t1.ID,t1.VCH,pid,NAME,PTEX from TEST_HCB_FQB t1,TEST_SUBLINK t2 where t1.id=t2.id) tt
|
||||
start with tt.id=1 CONNECT BY PRIOR tt.id = tt.pid ;
|
||||
|
||||
|
||||
explain (costs off) select tt.id,tt.name from (select t1.ID,t1.VCH,pid,NAME,PTEX from TEST_HCB_FQB t1,TEST_SUBLINK t2 where t1.id=t2.id) tt
|
||||
start with tt.id=1 CONNECT BY PRIOR tt.id = tt.pid ;
|
||||
|
||||
select test.id,test.pid,test.name
|
||||
from
|
||||
(select t1.id id, t1.pid pid, t1.name name from TEST_HCB_FQB t1
|
||||
union
|
||||
select t2.id id, t2.pid pid, t2.name name from TEST_HCB_FQB t2) test
|
||||
start with test.id = 12
|
||||
connect by prior test.id = test.pid;
|
||||
|
||||
/* startwith dealing with subqueries without alias */
|
||||
SELECT NAME,LEVEL,CONNECT_BY_ISLEAF,CONNECT_BY_ROOT(NAME),SYS_CONNECT_BY_PATH(NAME, '/')
|
||||
FROM (SELECT * FROM test_hcb_ptb)
|
||||
START WITH CHA IN ('afi','afg','afh')
|
||||
CONNECT BY PRIOR ID=PID
|
||||
ORDER SIBLINGS BY NAME;
|
||||
|
||||
SELECT NAME,LEVEL,CONNECT_BY_ISLEAF,CONNECT_BY_ROOT(NAME),SYS_CONNECT_BY_PATH(NAME, '/')
|
||||
FROM (SELECT * FROM test_hcb_ptb)
|
||||
START WITH CHA IN ('afi','afg','afh')
|
||||
CONNECT BY PRIOR ID=PID
|
||||
ORDER SIBLINGS BY 1;
|
||||
|
||||
SELECT NAME,LEVEL,CONNECT_BY_ISLEAF,CONNECT_BY_ROOT(NAME),SYS_CONNECT_BY_PATH(NAME, '/')
|
||||
FROM (SELECT * FROM test_hcb_ptb)
|
||||
START WITH CHA IN ('afi','afg','afh')
|
||||
CONNECT BY PRIOR ID=PID
|
||||
ORDER SIBLINGS BY 999;
|
||||
|
||||
SELECT NAME,LEVEL,CONNECT_BY_ISLEAF,CONNECT_BY_ROOT(NAME),SYS_CONNECT_BY_PATH(NAME, '/')
|
||||
FROM (SELECT * FROM test_hcb_ptb)
|
||||
START WITH CHA IN ('afi','afg','afh')
|
||||
CONNECT BY PRIOR ID=PID
|
||||
ORDER SIBLINGS BY 1, LEVEL;
|
||||
|
||||
SELECT NAME,LEVEL,CONNECT_BY_ISLEAF,CONNECT_BY_ROOT(NAME),SYS_CONNECT_BY_PATH(NAME, '/')
|
||||
FROM (SELECT * FROM test_hcb_ptb)
|
||||
START WITH CHA IN ('afi','afg','afh')
|
||||
CONNECT BY PRIOR ID=PID
|
||||
ORDER SIBLINGS BY 1, HUAWEI;
|
||||
|
||||
/* check siblings ordering */
|
||||
SELECT NAME,LEVEL,CONNECT_BY_ISLEAF,SYS_CONNECT_BY_PATH(NAME,'|'),CONNECT_BY_ROOT(NAME)
|
||||
FROM test_hcb_ptb
|
||||
START WITH (ID=168 or ID=169)
|
||||
CONNECT BY ID = PRIOR PID
|
||||
ORDER SIBLINGS BY NAME ASC;
|
||||
|
||||
-- connect_by_root/sys_connect_by_path() unsupported cases
|
||||
explain
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root name_desc, sys_connect_by_path(level, '@')
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
|
||||
-- sys_connect_by_path() only supports char type
|
||||
explain
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root name_desc, sys_connect_by_path(id, '@')
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY PRIOR id = fatherid;
|
||||
|
||||
/* sys_connect_by_path & connect_by_root can support char(xx) */
|
||||
SELECT name,LEVEL,connect_by_root(CHA)
|
||||
FROM test_hcb_fqb
|
||||
START WITH ID = 1
|
||||
CONNECT BY PRIOR CHA = PCHA
|
||||
ORDER BY ID ASC;
|
||||
|
||||
SELECT name,level,connect_by_root t1.cha as cha_col
|
||||
FROM test_hcb_fqb t1
|
||||
START WITH id = 1
|
||||
CONNECT BY PRIOR cha = pcha
|
||||
ORDER BY id ASC;
|
||||
|
||||
SELECT name,LEVEL,sys_connect_by_path(CHA, '==》')
|
||||
FROM test_hcb_fqb
|
||||
START WITH ID = 1
|
||||
CONNECT BY PRIOR CHA = PCHA
|
||||
ORDER BY ID ASC;
|
||||
|
||||
/* empty delimiter in sys_connect_by_path(VCH,'') should be rejected */
|
||||
SELECT name,LEVEL,sys_connect_by_path(VCH,'')
|
||||
FROM test_hcb_ptb
|
||||
START WITH ID = 1
|
||||
CONNECT BY PRIOR CHA = PCHA
|
||||
ORDER BY ID ASC;
|
||||
|
||||
/* start with null must not cause core-dump error */
|
||||
SELECT *
|
||||
FROM test_hcb_ptb
|
||||
START WITH NULL
|
||||
CONNECT BY PRIOR CHA = PCHA
|
||||
ORDER BY ID ASC;
|
||||
|
||||
/* start with pbe */
|
||||
PREPARE sthpt(int) AS SELECT t1.id,t1.pid,t1.name FROM test_hcb_ptb t1 START WITH id = $1 CONNECT BY PRIOR pid=id;
|
||||
EXECUTE sthpt(141);
|
||||
|
||||
/* with-clause used in startwith rewrite */
|
||||
explain (costs off) with subquery (id,pid,name) as
|
||||
(
|
||||
select t1.id,t1.pid,t1.name, LEVEL from test_hcb_ptb t1 where level>=1
|
||||
start with id = 141 connect by prior pid=id
|
||||
)
|
||||
select t1.id,t1.pid,t1.name,LEVEL from subquery t1
|
||||
start with id = 141 connect by prior pid=id;
|
||||
|
||||
explain (costs off) select t1.id,t1.pid,t1.name,LEVEL
|
||||
from (select t2.id,t2.pid,t2.name,LEVEL from test_hcb_ptb t2 where level>=1 start with t2.id = 141 connect by prior pid=id) t1
|
||||
where level>=1 start with id = 141 connect by prior pid=id;
|
||||
|
||||
/* core issue */
|
||||
explain select sysdate from test_hcb_ptb t1 start with id = 141 connect by prior pid=id;
|
||||
select count(sysdate) from test_hcb_ptb t1 start with id = 141 connect by prior pid=id;
|
||||
|
||||
/* core issue sys_connect_by_path(cosnt) core issue */
|
||||
select t1.id,t1.pid,LEVEL,sys_connect_by_path(null, '->') pa, t1.name from test_hcb_ptb t1 start with id = 141 connect by prior id = pid;
|
||||
select t1.id,t1.pid,LEVEL,sys_connect_by_path('id', '->') pa, t1.name from test_hcb_ptb t1 start with id = 141 connect by prior id = pid;
|
||||
select t1.id,t1.pid,LEVEL,sys_connect_by_path(' ', '->') pa, t1.name from test_hcb_ptb t1 start with id = 141 connect by prior id = pid;
|
||||
|
||||
/* core issue, check args */
|
||||
explain select t1.id,t1.pid,t1.name,level from test_hcb_ptb t1 start with id=141 connect by prior id=pid Order By NLSSORT ( id, ' NLS_SORT = SCHINESE_PINYIN_M ' );
|
||||
select t1.id,t1.pid,t1.name,level from test_hcb_ptb t1 start with id=141 connect by prior id=pid Order By NLSSORT ( id, ' NLS_SORT = SCHINESE_PINYIN_M ' );
|
||||
|
||||
/* core issue, check args */
|
||||
drop table if exists region cascade;
|
||||
create table region
|
||||
(
|
||||
region_cd varchar(50) primary key ,
|
||||
REGION_MGR_ASSOCIATE_ID number(18,9),
|
||||
c1 serial
|
||||
);
|
||||
|
||||
select region_mgr_associate_id from region;
|
||||
|
||||
drop table if exists item_price_history cascade;
|
||||
create table item_price_history
|
||||
(
|
||||
ITEM_ID number(39,10) primary key ,
|
||||
LOCATION_ID number(2,0) NULL,c1 serial
|
||||
);
|
||||
|
||||
|
||||
SELECT (MIN(region_cd)) Column_001, length(CAST('B' AS bytea), 'UTF8') Column_002
|
||||
FROM region , item_price_history
|
||||
WHERE REGION_MGR_ASSOCIATE_ID = ITEM_ID
|
||||
START WITH REGION_MGR_ASSOCIATE_ID NOT LIKE '_W_'
|
||||
CONNECT BY PRIOR LOCATION_ID = REGION_MGR_ASSOCIATE_ID
|
||||
GROUP BY 2;
|
||||
|
||||
drop table item_price_history;
|
||||
drop table region;
|
||||
|
||||
/* */
|
||||
create table test1(id int,pid int,name text, level int);
|
||||
create table test2(id int,pid int,name text, connect_by_iscycle int);
|
||||
create table test3(id int,pid int,name text, connect_by_isleaf int);
|
||||
create table test4(id int,pid int,name text, c4 int);
|
||||
|
||||
insert into test1 select id,pid,name,id%10 from test_hcb_ptb;
|
||||
insert into test2 select id,pid,name,id%10 from test_hcb_ptb;
|
||||
insert into test3 select id,pid,name,id%10 from test_hcb_ptb;
|
||||
insert into test4 select id,pid,name,id%10 from test_hcb_ptb;
|
||||
|
||||
/* level/connect_by_iscycle/connect_by_isleaf is for connect by's level value */
|
||||
select id,pid,name,test1.level, level from test1 start with id = 141 connect by prior pid=id;
|
||||
select id,pid,name,test2.connect_by_iscycle, connect_by_iscycle from test2 start with id = 141 connect by prior pid=id;
|
||||
select id,pid,name,test3.connect_by_isleaf, connect_by_isleaf from test3 start with id = 141 connect by prior pid=id;
|
||||
|
||||
drop table test1;
|
||||
drop table test2;
|
||||
drop table test3;
|
||||
drop table test4;
|
||||
|
||||
/* */
|
||||
/* 查询1 */
|
||||
SELECT TRAIT_VALUE_CD
|
||||
FROM trait_value
|
||||
START WITH TRAIT_VALUE_CD=TRAIT_VALUE_CD
|
||||
CONNECT BY PRIOR UOM_CD LIKE '_E_';
|
||||
|
||||
|
||||
create table region
|
||||
(
|
||||
region_cd varchar(50) primary key ,
|
||||
REGION_MGR_ASSOCIATE_ID number(18,9),c1 serial
|
||||
);
|
||||
|
||||
create table item_price_history
|
||||
(
|
||||
ITEM_ID number(39,10) primary key ,
|
||||
LOCATION_ID number(2,0) NULL,c1 serial
|
||||
);
|
||||
|
||||
INSERT INTO REGION VALUES ('A', 0.123433);
|
||||
INSERT INTO REGION VALUES ('B', NULL);
|
||||
INSERT INTO REGION VALUES ('C', 2.232008908);
|
||||
INSERT INTO REGION VALUES ('D', 3.878789);
|
||||
INSERT INTO REGION VALUES ('E', 4.89060603);
|
||||
INSERT INTO REGION VALUES ('F', 5.82703827);
|
||||
INSERT INTO REGION VALUES ('G', NULL);
|
||||
INSERT INTO REGION VALUES ('H', 7.3829083);
|
||||
|
||||
INSERT INTO ITEM_PRICE_HISTORY VALUES (0.12, 4);
|
||||
INSERT INTO ITEM_PRICE_HISTORY VALUES (1.3, 1);
|
||||
INSERT INTO ITEM_PRICE_HISTORY VALUES (2.23, NULL);
|
||||
INSERT INTO ITEM_PRICE_HISTORY VALUES (3.33, 3);
|
||||
INSERT INTO ITEM_PRICE_HISTORY VALUES (4.98, 4);
|
||||
INSERT INTO ITEM_PRICE_HISTORY VALUES (5.01, 5);
|
||||
INSERT INTO ITEM_PRICE_HISTORY VALUES (6, 6);
|
||||
INSERT INTO ITEM_PRICE_HISTORY VALUES (0.7, 7);
|
||||
INSERT INTO ITEM_PRICE_HISTORY VALUES (0.08, 8);
|
||||
INSERT INTO ITEM_PRICE_HISTORY VALUES (9.12, 9);
|
||||
|
||||
/* 查询2 */
|
||||
SELECT 1
|
||||
FROM region , item_price_history
|
||||
WHERE REGION_MGR_ASSOCIATE_ID = ITEM_ID
|
||||
START WITH REGION_MGR_ASSOCIATE_ID NOT LIKE '_W_'
|
||||
CONNECT BY PRIOR LOCATION_ID = REGION_MGR_ASSOCIATE_ID;
|
||||
|
||||
drop table region;
|
||||
drop table item_price_history;
|
||||
|
||||
/* */
|
||||
create table test1(c1 int, c2 int, c3 int);
|
||||
insert into test1 values(1,1,1);
|
||||
insert into test1 values(2,2,2);
|
||||
|
||||
-- encountered with 200 iteration limit
|
||||
select * from test1 t1 start with c1=1 connect by prior c2<>c3;
|
||||
-- will return result when cycle is met
|
||||
select * from test1 t1 start with c1=1 connect by NOCYCLE prior c2<>c3;
|
||||
|
||||
drop table test1;
|
||||
|
||||
-- error out a case when NOCYCLE is not specify and use connect_by_iscycle
|
||||
select t1.id, LEVEL, connect_by_iscycle from test_hcb_ptb t1 start with id = 1 connect by prior id = pid;
|
||||
|
||||
|
||||
create table mag_area
|
||||
(
|
||||
area_code varchar(10),
|
||||
area_name varchar(120),
|
||||
area_short_name varchar(120),
|
||||
local_name varchar(80),
|
||||
belong_area_code varchar(10),
|
||||
bank_level varchar(8),
|
||||
contry_code varchar(5),
|
||||
part_code varchar(5),
|
||||
time_zone varchar(9),
|
||||
bank_code varchar(10),
|
||||
group_code varchar(5),
|
||||
mag_area_grade varchar(3),
|
||||
mag_area_status varchar(1),
|
||||
mag_area_broad varchar(1)
|
||||
);
|
||||
|
||||
create table mag_image_tpl
|
||||
(
|
||||
seq varchar(20),
|
||||
area_code varchar(10),
|
||||
archive_type varchar(3),
|
||||
busitype varchar(8),
|
||||
image_type varchar(8),
|
||||
app_type varchar(10),
|
||||
rule_id varchar(10),
|
||||
valid_flag varchar(1),
|
||||
modify_branch varchar(10),
|
||||
modify_user varchar(9),
|
||||
modify_time varchar(14)
|
||||
);
|
||||
|
||||
|
||||
explain
|
||||
select a.rule_id, b.mag_area_grade,
|
||||
max(b.mag_area_grade) OVER (PARTITION BY archive_type, busitype,image_type,app_type) max_level
|
||||
FROM mag_image_tpl a, mag_area b
|
||||
WHERE a.AREA_CODE IN (
|
||||
SELECT area_code
|
||||
FROM mag_area
|
||||
START WITH area_code = '1'
|
||||
CONNECT BY PRIOR belong_area_code = area_code
|
||||
)
|
||||
AND a.archive_type = 'A'
|
||||
AND a.BUSITYPE = 'B'
|
||||
AND a.area_code = b.area_code;
|
||||
|
||||
|
||||
select a.rule_id, b.mag_area_grade,
|
||||
max(b.mag_area_grade) OVER (PARTITION BY archive_type, busitype,image_type,app_type) max_level
|
||||
FROM mag_image_tpl a, mag_area b
|
||||
WHERE a.AREA_CODE IN (
|
||||
SELECT area_code
|
||||
FROM mag_area
|
||||
START WITH area_code = '1'
|
||||
CONNECT BY PRIOR belong_area_code = area_code
|
||||
)
|
||||
AND a.archive_type = 'A'
|
||||
AND a.BUSITYPE = 'B'
|
||||
AND a.area_code = b.area_code;
|
||||
|
||||
drop table mag_area;
|
||||
drop table mag_image_tpl;
|
||||
|
||||
SELECT id, sys_connect_by_path(name_desc, '@') || id
|
||||
FROM test_area
|
||||
START WITH name = '耒阳市'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
|
||||
explain
|
||||
SELECT table_name || NVL('test','_B$') AS table_name
|
||||
FROM (SELECT TRIM(SUBSTR(txt,
|
||||
INSTR(txt, ',', 1, LEVEL) + 1,
|
||||
INSTR(txt, ',', 1, LEVEL + 1) -
|
||||
INSTR(txt, ',', 1, LEVEL) - 1)) AS table_name
|
||||
FROM (SELECT ',' || REPLACE('test' , ' ', '') || ',' txt FROM sys_dummy)
|
||||
CONNECT BY LEVEL <= LENGTH(REPLACE('test', ' ', '')) - LENGTH(REPLACE(REPLACE('test', ' ', ''), ',', '')) + 1);
|
||||
|
||||
SELECT table_name || NVL('test','_B$') AS table_name
|
||||
FROM (SELECT TRIM(SUBSTR(txt,
|
||||
INSTR(txt, ',', 1, LEVEL) + 1,
|
||||
INSTR(txt, ',', 1, LEVEL + 1) -
|
||||
INSTR(txt, ',', 1, LEVEL) - 1)) AS table_name
|
||||
FROM (SELECT ',' || REPLACE('test' , ' ', '') || ',' txt FROM sys_dummy)
|
||||
CONNECT BY LEVEL <= LENGTH(REPLACE('test', ' ', '')) - LENGTH(REPLACE(REPLACE('test', ' ', ''), ',', '')) + 1);
|
||||
|
||||
-- fix infinite recursive
|
||||
explain select * from t1 start with id = 1 connect by prior id != pid;
|
||||
|
||||
create table tsc_rtbl(c_int int,c_varchar1 varchar,c_varchar2 varchar);
|
||||
alter table tsc_rtbl drop column c_varchar2;
|
||||
alter table tsc_rtbl add column c_varchar2 varchar;
|
||||
|
||||
select c_int,c_varchar1,c_varchar2 from tsc_rtbl
|
||||
start with c_int<10 connect by nocycle prior c_int=c_int;
|
||||
|
||||
create table t1_area (id int4,name text, fatherid int4, name_desc text);
|
||||
insert into t1_area values (1, '中国', 0, 'China');
|
||||
insert into t1_area values (2, '湖南省',1 , 'Hunan');
|
||||
insert into t1_area values (3, '广东省',1 , 'Guangdong');
|
||||
insert into t1_area values (4, '海南省',1 , 'Hainan');
|
||||
insert into t1_area values (5, '河北省',1 , 'Hebei');
|
||||
insert into t1_area values (6, '河南省',1 , 'Henan');
|
||||
insert into t1_area values (7, '山东省',1 , 'Shandong');
|
||||
insert into t1_area values (8, '湖北省',1 , 'Hubei');
|
||||
insert into t1_area values (9, '江苏省',1 , 'Jiangsu');
|
||||
insert into t1_area values (10,'深圳市',3 , 'Shenzhen');
|
||||
insert into t1_area values (11,'长沙市',2 , 'Changsha');
|
||||
insert into t1_area values (22,'祁北县',13, 'Qibei');
|
||||
insert into t1_area values (12,'南山区',10, 'Nanshan');
|
||||
insert into t1_area values (21,'祁西县',13, 'Qixi');
|
||||
insert into t1_area values (13,'衡阳市',2 , 'Hengyang');
|
||||
insert into t1_area values (14,'耒阳市',13, 'Leiyang');
|
||||
insert into t1_area values (15,'龙岗区',10, 'Longgang');
|
||||
insert into t1_area values (16,'福田区',10, 'Futian');
|
||||
insert into t1_area values (17,'宝安区',10, 'Baoan');
|
||||
insert into t1_area values (19,'祁东县',13, 'Qidong');
|
||||
insert into t1_area values (18,'常宁市',13, 'Changning');
|
||||
insert into t1_area values (20,'祁南县',13, 'Qinan');
|
||||
|
||||
SELECT *, connect_by_root(name_desc), sys_connect_by_path(name_desc, '->')
|
||||
FROM t1_area
|
||||
START WITH name = '耒阳市'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
|
||||
--创建drop column并加回场景
|
||||
alter table t1_area drop column name_desc;
|
||||
alter table t1_area add column name_desc text;
|
||||
|
||||
-- 原有备drop列为空
|
||||
SELECT *, connect_by_root(name_desc), sys_connect_by_path(name_desc, '->')
|
||||
FROM t1_area
|
||||
START WITH name = '耒阳市'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
|
||||
-- 新插入相同数据,原有drop列后的空值和当前有效值并存
|
||||
insert into t1_area values (1, '中国', 0, 'China');
|
||||
insert into t1_area values (2, '湖南省',1 , 'Hunan');
|
||||
insert into t1_area values (3, '广东省',1 , 'Guangdong');
|
||||
insert into t1_area values (4, '海南省',1 , 'Hainan');
|
||||
insert into t1_area values (5, '河北省',1 , 'Hebei');
|
||||
insert into t1_area values (6, '河南省',1 , 'Henan');
|
||||
insert into t1_area values (7, '山东省',1 , 'Shandong');
|
||||
insert into t1_area values (8, '湖北省',1 , 'Hubei');
|
||||
insert into t1_area values (9, '江苏省',1 , 'Jiangsu');
|
||||
insert into t1_area values (10,'深圳市',3 , 'Shenzhen');
|
||||
insert into t1_area values (11,'长沙市',2 , 'Changsha');
|
||||
insert into t1_area values (22,'祁北县',13, 'Qibei');
|
||||
insert into t1_area values (12,'南山区',10, 'Nanshan');
|
||||
insert into t1_area values (21,'祁西县',13, 'Qixi');
|
||||
insert into t1_area values (13,'衡阳市',2 , 'Hengyang');
|
||||
insert into t1_area values (14,'耒阳市',13, 'Leiyang');
|
||||
insert into t1_area values (15,'龙岗区',10, 'Longgang');
|
||||
insert into t1_area values (16,'福田区',10, 'Futian');
|
||||
insert into t1_area values (17,'宝安区',10, 'Baoan');
|
||||
insert into t1_area values (19,'祁东县',13, 'Qidong');
|
||||
insert into t1_area values (18,'常宁市',13, 'Changning');
|
||||
insert into t1_area values (20,'祁南县',13, 'Qinan');
|
||||
|
||||
SELECT *, connect_by_root(name_desc), sys_connect_by_path(name_desc, '->')
|
||||
FROM t1_area
|
||||
START WITH name = '耒阳市'
|
||||
CONNECT BY id = PRIOR fatherid;
|
||||
|
||||
SELECT * FROM t1_area START WITH id in ('1','2') CONNECT BY PRIOR fatherid = id;
|
||||
|
||||
SELECT * FROM t1_area START WITH (cast(id as varchar) COLLATE "C") in (cast(+ (id) as varchar) COLLATE "C") and id < 4 connect by id = prior fatherid;
|
||||
|
||||
SELECT * FROM t1_area, tsc_rtbl START WITH id = 1 CONNECT BY PRIOR fatherid = id;
|
||||
|
||||
SELECT *, connect_by_root(name_desc), sys_connect_by_path(name_desc, '->')
|
||||
FROM t1_area;
|
||||
|
||||
/* fix start with in with clause */
|
||||
explain (costs off) WITH WITH_001 AS (SELECT 1 FROM offers_20050701 ,trait_value START WITH PARTY_ID=TRAIT_VAL CONNECT BY PRIOR TRAIT_VALUE_CD LIKE '%V%')
|
||||
SELECT mfg
|
||||
FROM brand ,trait_value ,WITH_001
|
||||
START WITH TRAIT_VALUE_CD=brand_name
|
||||
CONNECT BY PRIOR brand_cd=UOM_CD;
|
||||
|
||||
WITH WITH_001 AS (SELECT 1 FROM offers_20050701 ,trait_value START WITH PARTY_ID=TRAIT_VAL CONNECT BY PRIOR TRAIT_VALUE_CD LIKE '%V%')
|
||||
SELECT mfg
|
||||
FROM brand ,trait_value ,WITH_001
|
||||
START WITH TRAIT_VALUE_CD=brand_name
|
||||
CONNECT BY PRIOR brand_cd=UOM_CD;
|
||||
|
||||
/* fix reference to level in connect by function calls */
|
||||
SELECT 1, level FROM t1_area CONNECT BY length(level) IS NULL;
|
||||
|
||||
/* prior params of procedure */
|
||||
create or replace function test_tmp1(out id int,out pid int,out name varchar,out level int) return SETOF RECORD
|
||||
IS
|
||||
declare
|
||||
CURSOR C1(sedid int) IS select t1.id,t1.pid,t1.name,level from test_hcb_ptb t1 start with id = sedid connect by prior pid=id;
|
||||
begin
|
||||
open C1(141);
|
||||
loop
|
||||
fetch C1 into id,pid,name,level;
|
||||
EXIT WHEN C1%NOTFOUND;
|
||||
return next;
|
||||
end loop;
|
||||
close C1;
|
||||
end;
|
||||
/
|
||||
select * from test_tmp1();
|
||||
drop procedure test_tmp1;
|
||||
|
||||
drop table t1_area;
|
||||
drop table tsc_rtbl;
|
||||
|
||||
-- 原问题单场景,connect_by_root(1)出现在在表达式中报错
|
||||
explain
|
||||
select t1.id,t1.pid,t1.name,LEVEL le,connect_by_root(1), connect_by_root(id)
|
||||
from test_hcb_ptb t1
|
||||
where connect_by_root(1) > 0
|
||||
start with id = 141
|
||||
connect by prior pid=id;
|
||||
|
||||
select t1.id,t1.pid,t1.name,LEVEL le,connect_by_root(1), connect_by_root(id)
|
||||
from test_hcb_ptb t1
|
||||
where connect_by_root(1) > 0
|
||||
start with id = 141
|
||||
connect by prior pid=id;
|
||||
|
||||
-- 扩展场景, connect_by_root(id)报错找不到列
|
||||
explain
|
||||
select t1.id,t1.pid,t1.name,LEVEL le,connect_by_root(1), connect_by_root(id)
|
||||
from test_hcb_ptb t1
|
||||
where connect_by_root(id) > 0
|
||||
start with id = 141
|
||||
connect by prior pid=id;
|
||||
|
||||
select t1.id,t1.pid,t1.name,LEVEL le,connect_by_root(1), connect_by_root(id)
|
||||
from test_hcb_ptb t1
|
||||
where connect_by_root(id) > 0
|
||||
start with id = 141
|
||||
connect by prior pid=id;
|
||||
|
||||
|
||||
-- 扩展场景,sys_connect_by_path(123, '-') is not null
|
||||
explain
|
||||
select t1.id,t1.pid,t1.name,LEVEL le,connect_by_root(1), connect_by_root(id), sys_connect_by_path(123, '-')
|
||||
from test_hcb_ptb t1
|
||||
where sys_connect_by_path(123, '-') is not null
|
||||
start with id = 141
|
||||
connect by prior pid=id;
|
||||
|
||||
create table ctI as select t1.id,t1.pid,t1.name,level as le from test_hcb_ptb t1 start with id=141 connect by prior id=pid;
|
||||
|
||||
create table ctII as select t1.id,t1.pid,t1.name,level from test_hcb_ptb t1 start with id=141 connect by prior id=pid;
|
||||
|
||||
\d ctI;
|
||||
|
||||
\d ctII;
|
||||
|
||||
drop table ctI;
|
||||
|
||||
drop table ctII;
|
||||
|
||||
/*
|
||||
* NOTE: need do upgrade change to have syc_conenct_by_path()/connect_by_root() to be volatile
|
||||
*/
|
||||
/*
|
||||
select t1.id,t1.pid,t1.name,LEVEL le,connect_by_root(1), connect_by_root(id), sys_connect_by_path(123, '-')
|
||||
from test_hcb_ptb t1
|
||||
where sys_connect_by_path(123, '-') is not null
|
||||
start with id = 141
|
||||
connect by prior pid=id;
|
||||
*/
|
||||
|
||||
-- 扩展场景,sys_connect_by_path(123, '-') 验证能够被正确匹配
|
||||
explain
|
||||
select t1.id,t1.pid,t1.name,LEVEL le,connect_by_root(1), connect_by_root(id), sys_connect_by_path(123, '-')
|
||||
from test_hcb_ptb t1
|
||||
where sys_connect_by_path(123, '-') like '-123-123-123%'
|
||||
start with id = 141
|
||||
connect by prior pid=id;
|
||||
|
||||
/*
|
||||
* NOTE: need do upgrade change to have syc_conenct_by_path()/connect_by_root() to be volatile
|
||||
*/
|
||||
/*
|
||||
select t1.id,t1.pid,t1.name,LEVEL le,connect_by_root(1), connect_by_root(id), sys_connect_by_path(123, '-')
|
||||
from test_hcb_ptb t1
|
||||
where sys_connect_by_path(123, '-') like '-123-123-123%'
|
||||
start with id = 141
|
||||
connect by prior pid=id;
|
||||
*/
|
||||
|
||||
/* testing distinct qualifier */
|
||||
select distinct id,pid,name,LEVEL from t1 start with id = 1 connect by prior pid=id order by 1;
|
||||
|
||||
/* testing NOT expression */
|
||||
select t1.id, t1.pid, t1.name from t1 start with not id=1 connect by prior pid=id;
|
||||
|
||||
/* testing func expr in connect by clause */
|
||||
explain select trim(t1.name) from test_hcb_ptb t1 connect by trim(t1.name) is not null;
|
||||
|
||||
/* fix create table as with start with */
|
||||
create table ct as select t1.id,t1.pid,t1.name,level from test_hcb_ptb t1 start with id=141 connect by prior id=pid;
|
||||
drop table ct;
|
||||
|
||||
set current_schema = public;
|
||||
create table t1(c1 int,c2 int,c3 int);
|
||||
insert into t1 values(1,1,1);
|
||||
insert into t1 values(2,2,2);
|
||||
select *, connect_by_iscycle from t1 start with c1=1 connect by nocycle prior c1=c2 order siblings by 1,2;
|
||||
|
||||
insert into t1 values(1,1,1);
|
||||
insert into t1 values(2,2,2);
|
||||
select *, connect_by_iscycle from t1 start with c1=1 connect by nocycle prior c1=c2 order siblings by 1,2;
|
||||
|
||||
insert into t1 values(1,NULL,1);
|
||||
select *, connect_by_iscycle from t1 start with c1=1 connect by nocycle prior c1=c2 order siblings by 1,2 nulls first;
|
||||
select *, connect_by_iscycle from t1 start with c1=1 connect by nocycle prior c1=c2 order siblings by 1,2 nulls last;
|
||||
delete from t1 where c2 is null;
|
||||
|
||||
select *, connect_by_iscycle from t1 start with c1<3 connect by nocycle prior c1<c2 order siblings by NLSSORT (c1, ' NLS_SORT = generic_m_ci ');
|
||||
|
||||
select max(c1) + level from t1 connect by prior c1 = c2;
|
||||
|
||||
select * from t1 connect by cast(level as bigint) < 3;
|
||||
|
||||
select * from t1 connect by cast(level as int4) < 3;
|
||||
|
||||
explain select * from t1 connect by level is not null;
|
||||
|
||||
select * from t1 connect by level is not null and level < 3;
|
||||
|
||||
select * from t1 connect by level;
|
||||
|
||||
select t1.id a.d jack from t1;
|
||||
|
||||
select t1.id bauer jack from t1;
|
||||
|
||||
drop table t1;
|
||||
|
||||
/* limit + startwith 场景下执行阶段targetlist报错 */
|
||||
CREATE TABLE log_part (
|
||||
ts timestamp(6) without time zone DEFAULT now() NOT NULL,
|
||||
op character(1),
|
||||
act_no numeric(38,0),
|
||||
old_blc numeric(38,0),
|
||||
num numeric(38,0),
|
||||
threadid bigint,
|
||||
index integer,
|
||||
tran integer
|
||||
)
|
||||
WITH (orientation=row, compression=no)
|
||||
PARTITION BY RANGE (ts)
|
||||
INTERVAL('1 day')
|
||||
(
|
||||
PARTITION p_2020_05_21 VALUES LESS THAN ('2020-05-21') TABLESPACE pg_default
|
||||
)
|
||||
ENABLE ROW MOVEMENT;
|
||||
|
||||
insert into log_part values('2021-09-24 10:12:19.451125','m',255, 10000000, -374929792, 39, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.451125','a',548, 10000000, 374929792, 39, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.449826','m', 39, 10000000, -473910067, 97, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.451221','m',250, 10000000, -757146539, 63, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.449643','m',916, 10000000, -418707874, 100, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.451052','m',510, 10000000, -868384331, 45, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.451039','m',541, 10000000, -782801693, 101, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.450232','m', 4, 10000000, -794225803, 33, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.450352','m',123, 10000000, -494836087, 58, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.449622','m',876, 10000000, -79442930, 60, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.449785','m', 21, 10000000, -560326111, 65, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.449828','m',484, 10000000, -571750221, 29, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.449657','m',167, 10000000, -146895512, 106, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.449826','a', 35, 10000000, 473910067, 97, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.451221','a',540, 10000000, 757146539, 63, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.449706','m',118, 10000000, -318894193, 50, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.501816','m',105, 10000000, -997671676, 39, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.449602','m',858, 10000000, -207656402, 28, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.450566','m',607, 10000000, -479468765, 30, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.451052','a',132, 10000000, 868384331, 45, 0, 0);
|
||||
insert into log_part values('2021-09-24 10:12:19.451039','a',891, 10000000, 782801693, 101, 0, 0);
|
||||
|
||||
explain
|
||||
select * from (select * from log_part where act_no=250)
|
||||
start with old_blc=10000000 connect by prior old_blc + prior num = old_blc and act_no=prior act_no limit 10;
|
||||
select * from (select * from log_part where act_no=250)
|
||||
start with old_blc=10000000 connect by prior old_blc + prior num = old_blc and act_no=prior act_no limit 10;
|
||||
|
||||
explain
|
||||
select *, connect_by_root old_blc from (select * from log_part where act_no=250)
|
||||
start with old_blc=10000000 connect by prior old_blc + prior num = old_blc and act_no=prior act_no limit 10;
|
||||
|
||||
select *, connect_by_root old_blc from (select * from log_part where act_no=250)
|
||||
start with old_blc=10000000 connect by prior old_blc + prior num = old_blc and act_no=prior act_no limit 10;
|
||||
|
||||
select *, connect_by_root old_blc alias_old_blc from (select * from log_part where act_no=250)
|
||||
start with old_blc=10000000 connect by prior old_blc + prior num = old_blc and act_no=prior act_no limit 10;
|
||||
|
||||
SELECT *, CONNECT_BY_ROOT old_blc AS alias_old_blc FROM (SELECT * FROM log_part WHERE act_no=250)
|
||||
START WITH old_blc=10000000 CONNECT BY PRIOR old_blc + PRIOR num = old_blc AND act_no = PRIOR act_no LIMIT 10;
|
||||
|
||||
explain
|
||||
select op , act_no , old_blc , num , threadid , index , tran ,level from log_part
|
||||
start with old_blc=10000000 connect by prior old_blc + prior num = old_blc and act_no=prior act_no
|
||||
order by 1,2,3,4 limit 10;
|
||||
|
||||
select op , act_no , old_blc , num , threadid , index , tran ,level from log_part
|
||||
start with old_blc=10000000 connect by prior old_blc + prior num = old_blc and act_no=prior act_no
|
||||
order by 1,2,3,4 limit 10;
|
||||
|
||||
drop table log_part;
|
||||
|
||||
set current_schema=swtest;
|
||||
|
||||
EXPLAIN SELECT * FROM test_area START WITH name = '中国' CONNECT BY PRIOR id = fatherid limit 10;
|
||||
|
||||
SELECT * FROM test_area START WITH name = '中国' CONNECT BY PRIOR id = fatherid limit 10;
|
||||
|
||||
|
||||
set max_recursive_times=100000000;
|
||||
|
||||
create table tt22(x int);
|
||||
|
||||
create or replace view dual as select 'x' x;
|
||||
|
||||
insert into tt22 select level from dual connect by level <=1000000;
|
||||
|
||||
select count(*) from tt22;
|
||||
|
||||
set max_recursive_times=200;
|
||||
|
||||
insert into tt22 select level from dual connect by level <=1000000;
|
||||
|
||||
drop table tt22;
|
||||
|
||||
/* 修复RecursiveUnion的inner分支备planning成BaseResult节点 */
|
||||
explain select t1.id,t1.pid,t1.name from test_hcb_ptb t1 start with id=141 connect by (prior pid)=id and prior pid>10 and 1=0;
|
||||
select t1.id,t1.pid,t1.name from test_hcb_ptb t1 start with id=141 connect by (prior pid)=id and prior pid>10 and 1=0;
|
||||
|
||||
explain select t1.id,t1.pid,t1.name from test_hcb_ptb t1 start with id=141 connect by (prior pid)=id and prior pid>10 and null;
|
||||
select t1.id,t1.pid,t1.name from test_hcb_ptb t1 start with id=141 connect by (prior pid)=id and prior pid>10 and null;
|
||||
|
||||
/* connect by level/rownum 不支持not并且in 数据不准确 */
|
||||
create table core_060(id varchar);
|
||||
insert into core_060 values ('a'),('b'),('c');
|
||||
|
||||
SELECT id,level FROM core_060 CONNECT BY level in (1,2);
|
||||
SELECT id,level FROM core_060 CONNECT BY not (level>2);
|
||||
SELECT id,level FROM core_060 CONNECT BY cast(level as number(38,0))<3;
|
||||
|
||||
drop table core_060;
|
||||
|
||||
/* 存在子查询时,随着数据递归层数的增加,性能下降明显 */
|
||||
create table t_customer(id int, pid int,num int,depth int);
|
||||
-- verify nestloop can be material-optimized
|
||||
set enable_hashjoin = off;
|
||||
set enable_mergejoin = off;
|
||||
explain
|
||||
select * from ( select * from t_customer where id<1200040 and id>=1200000) start with id=1200010 connect by prior id=pid;
|
||||
select * from ( select * from t_customer where id<1200040 and id>=1200000) start with id=1200010 connect by prior id=pid;
|
||||
reset enable_hashjoin;
|
||||
reset enable_mergejoin;
|
||||
|
||||
-- verify nestloop can be material-optimized
|
||||
set enable_nestloop = off;
|
||||
set enable_mergejoin = off;
|
||||
explain
|
||||
select * from ( select * from t_customer where id<1200040 and id>=1200000) start with id=1200010 connect by prior id=pid;
|
||||
select * from ( select * from t_customer where id<1200040 and id>=1200000) start with id=1200010 connect by prior id=pid;
|
||||
reset enable_nestloop;
|
||||
reset enable_mergejoin;
|
||||
|
||||
-- verify mergejoin is no need to be material-optimized
|
||||
set enable_hashjoin = off;
|
||||
set enable_nestloop = off;
|
||||
explain
|
||||
select * from ( select * from t_customer where id<1200040 and id>=1200000) start with id=1200010 connect by prior id=pid;
|
||||
select * from ( select * from t_customer where id<1200040 and id>=1200000) start with id=1200010 connect by prior id=pid;
|
||||
reset enable_mergejoin;
|
||||
reset enable_nestloop;
|
||||
reset enable_hashjoin;
|
||||
|
||||
drop table t_customer;
|
||||
|
||||
-- test correlated sublink
|
||||
create table test_place as select id, name, tex from test_hcb_ptb;
|
||||
select t1.id,t1.pid,t1.name from test_hcb_ptb t1 start with not exists(select * from test_place where id=t1.id and id !=141) connect by prior pid=id;
|
||||
drop table test_place;
|
||||
|
||||
-- test where quals pushdown
|
||||
drop table if exists brand_sw3 cascade;
|
||||
create table brand_sw3
|
||||
(
|
||||
mfg varchar(500) primary key ,
|
||||
brand_cd varchar(500) ,
|
||||
brand_name varchar(100) ,
|
||||
brand_party_id number(18,10) NULL,c1 serial
|
||||
);
|
||||
|
||||
drop table if exists usview17_sw3 cascade;
|
||||
create table usview17_sw3
|
||||
(
|
||||
brand_party_id numeric(18,2) ,
|
||||
sales_tran_id numeric(12,5) ,
|
||||
item_qty numeric(5,0) ,
|
||||
mkb_cost_amt numeric(19,4) ,
|
||||
mkb_exp numeric
|
||||
);
|
||||
|
||||
SELECT MAX(t2.brand_party_id)-COUNT(t2.sales_tran_id)
|
||||
FROM brand_sw3 t1,usview17_sw3 t2
|
||||
WHERE t1.brand_name=PRIOR t1.brand_name
|
||||
AND PRIOR t1.brand_cd IS NOT NULL
|
||||
START WITH t1.mfg=t1.brand_name
|
||||
CONNECT BY NOCYCLE PRIOR t1.mfg
|
||||
BETWEEN t1.brand_name
|
||||
AND PRIOR t1.brand_name ;
|
||||
|
||||
SELECT MAX(t2.brand_party_id)-COUNT(t2.sales_tran_id)
|
||||
FROM brand_sw3 t1,usview17_sw3 t2
|
||||
where t1.brand_cd IS NOT NULL CONNECT BY rownum < 3;
|
||||
|
||||
drop table if exists brand_sw3 cascade;
|
||||
drop table if exists usview17_sw3 cascade;
|
||||
|
||||
create table sw_test1(c0 int);
|
||||
create table sw_test2(c0 text);
|
||||
|
||||
select * from sw_test1,sw_test2 where true connect by true;
|
||||
|
||||
drop table sw_test1;
|
||||
drop table sw_test2;
|
||||
36
src/test/regress/sql/sw_by_rownum_level.sql
Normal file
36
src/test/regress/sql/sw_by_rownum_level.sql
Normal file
@ -0,0 +1,36 @@
|
||||
set client_min_messages = error;
|
||||
set search_path=swtest;
|
||||
SET CLIENT_ENCODING='UTF8';
|
||||
|
||||
--accepted cases
|
||||
explain (costs off)
|
||||
select * from test_area CONNECT BY LEVEL <= LENGTH('SOME TEXT');
|
||||
explain (costs off)
|
||||
select *, LEVEL from test_area CONNECT BY LEVEL <= LENGTH('SOME TEXT');
|
||||
|
||||
explain (costs off)
|
||||
select * from test_area CONNECT BY ROWNUM <= LENGTH('SOME TEXT');
|
||||
explain (costs off)
|
||||
select *, ROWNUM from test_area CONNECT BY ROWNUM <= LENGTH('SOME TEXT');
|
||||
|
||||
explain (costs off)
|
||||
select * from test_area CONNECT BY LEVEL < LENGTH('SOME TEXT');
|
||||
explain (costs off)
|
||||
select *, LEVEL from test_area CONNECT BY LEVEL < LENGTH('SOME TEXT');
|
||||
|
||||
explain (costs off)
|
||||
select * from test_area CONNECT BY ROWNUM < LENGTH('SOME TEXT');
|
||||
explain (costs off)
|
||||
select *, ROWNUM from test_area CONNECT BY ROWNUM < LENGTH('SOME TEXT');
|
||||
|
||||
--rejected cases
|
||||
explain (costs off)
|
||||
select *, LEVEL from test_area CONNECT BY LEVEL > LENGTH('SOME TEXT');
|
||||
explain (costs off)
|
||||
select *, LEVEL from test_area CONNECT BY LEVEL >= LENGTH('SOME TEXT');
|
||||
explain (costs off)
|
||||
select * from test_area CONNECT BY APPLE > LENGTH('SOME TEXT');
|
||||
explain (costs off)
|
||||
select * from test_area CONNECT BY APPLE < LENGTH('SOME TEXT');
|
||||
explain (costs off)
|
||||
select * from test_area CONNECT BY APPLE <= LENGTH('SOME TEXT');
|
||||
16
src/test/regress/sql/sw_clearup.sql
Normal file
16
src/test/regress/sql/sw_clearup.sql
Normal file
@ -0,0 +1,16 @@
|
||||
set current_schema=swtest;
|
||||
|
||||
drop table if exists swtest.test_area;
|
||||
drop table if exists swtest.test_area2;
|
||||
drop table if exists swtest.t1;
|
||||
drop table if exists swtest.t2;
|
||||
drop table if exists swtest.test_hcb_ptb;
|
||||
drop table if exists swtest.test_hcb_fqb;
|
||||
drop table if exists swtest.test_sublink;
|
||||
drop table if exists swtest.test_hcb_ptbc;
|
||||
drop table if exists swtest.test_swcb_a;
|
||||
drop table if exists swtest.trait_value;
|
||||
drop table if exists swtest.offers_20050701;
|
||||
drop table if exists swtest.brand;
|
||||
|
||||
drop schema if exists swtest cascade;
|
||||
96
src/test/regress/sql/sw_icbc.sql
Normal file
96
src/test/regress/sql/sw_icbc.sql
Normal file
@ -0,0 +1,96 @@
|
||||
set client_min_messages = error;
|
||||
set search_path=swtest;
|
||||
SET CLIENT_ENCODING='UTF8';
|
||||
|
||||
--signle table columns test
|
||||
explain (costs off)
|
||||
select * from t1 start with id = 1 connect by prior id = pid;
|
||||
select * from t1 start with id = 1 connect by prior id = pid;
|
||||
|
||||
explain (costs off)
|
||||
select * from t1 start with t1.id = 1 connect by prior t1.id = t1.pid;
|
||||
select * from t1 start with t1.id = 1 connect by prior t1.id = t1.pid;
|
||||
|
||||
explain (costs off)
|
||||
select * from t1 as test start with test.id = 1 connect by prior test.id = test.pid;
|
||||
select * from t1 as test start with test.id = 1 connect by prior test.id = test.pid;
|
||||
|
||||
explain (costs off)
|
||||
select * from t1 start with id = 1 connect by prior id = pid order by id desc;
|
||||
select * from t1 start with id = 1 connect by prior id = pid order by id desc;
|
||||
|
||||
explain (costs off)
|
||||
select * from t1 start with id IN (select id from t2 where id = 1) connect by prior id = pid order by id desc;
|
||||
select * from t1 start with id IN (select id from t2 where id = 1) connect by prior id = pid order by id desc;
|
||||
|
||||
explain (costs off) select t1.id, t1.pid, t1.name from t1 start with id = 1 connect by prior id = pid;
|
||||
select t1.id, t1.pid, t1.name from t1 start with id = 1 connect by prior id = pid;
|
||||
|
||||
explain (costs off) select sum(name) from t1 start with id = 1 connect by prior id = pid group by id, pid;
|
||||
select sum(name) from t1 start with id = 1 connect by prior id = pid group by id, pid;
|
||||
|
||||
explain (costs off) select * from t1 start with id = 1 connect by prior id = pid and id IN (select id from t2);
|
||||
select * from t1 start with id = 1 connect by prior id = pid and id IN (select id from t2);
|
||||
|
||||
explain (costs off) select * from t1 start with id = 1 and id is not NULL connect by prior id = pid;
|
||||
select * from t1 start with id = 1 and id is not NULL connect by prior id = pid;
|
||||
|
||||
explain (costs off)
|
||||
select *
|
||||
from
|
||||
(select t1.id id, t1.pid pid, t1.name name from t1
|
||||
union
|
||||
select t1.id id, t1.pid pid, t1.name name from t1) as test
|
||||
start with test.id = 1
|
||||
connect by prior test.id = test.pid;
|
||||
|
||||
select *
|
||||
from
|
||||
(select t1.id id, t1.pid pid, t1.name name from t1
|
||||
union
|
||||
select t1.id id, t1.pid pid, t1.name name from t1) as test
|
||||
start with test.id = 1
|
||||
connect by prior test.id = test.pid;
|
||||
|
||||
explain (costs off)
|
||||
select *
|
||||
from
|
||||
(select *
|
||||
from(select t1.id id, t1.pid pid, t1.name name from t1
|
||||
union
|
||||
select t1.id id, t1.pid pid, t1.name name from t1) as test
|
||||
start with test.id = 1
|
||||
connect by prior test.id = test.pid) as tt
|
||||
CONNECT BY PRIOR tt.id = tt.pid
|
||||
START WITH tt.id = 1;
|
||||
|
||||
select *
|
||||
from
|
||||
(select *
|
||||
from(select t1.id id, t1.pid pid, t1.name name from t1
|
||||
union
|
||||
select t1.id id, t1.pid pid, t1.name name from t1) as test
|
||||
start with test.id = 1
|
||||
connect by prior test.id = test.pid) as tt
|
||||
CONNECT BY PRIOR tt.id = tt.pid
|
||||
START WITH tt.id = 1;
|
||||
|
||||
--test correlated sublink in targetlist
|
||||
explain select b.id, (select count(a.id) from t1 a where a.pid = b.id) c from t1 b
|
||||
start with b.id=1 connect by prior b.id = b.pid;
|
||||
|
||||
explain select * from t1 as test
|
||||
where not exists (select 1 from t1 where test.id = t1.id)
|
||||
start with test.id = 1 connect by prior test.id = test.pid;
|
||||
|
||||
--multiple tables case
|
||||
explain (costs off) select * from t1, t2 where t1.id = t2.id start with t1.id = t2.id and t1.id = 1 connect by prior t1.id = t1.pid;
|
||||
explain (costs off) select * from t1 join t2 on t1.id = t2.id start with t1.id = t2.id and t1.id = 1 connect by prior t1.id = t1.pid;
|
||||
explain (costs off) select * from t1, (select * from t2) as test where t1.id = test.id start with t1.id = test.id and t1.id = 1 connect by prior t1.id = t1.pid;
|
||||
|
||||
explain (costs off) select id, (select id from t2 start with t2.id = t1.id connect by t2.id = t1.id limit 1) from t1 where id = 1;
|
||||
|
||||
--unsupport case
|
||||
select prior id cc from t1 start with id = 1 connect by prior id = pid;
|
||||
|
||||
create INCREMENTAL MATERIALIZED view mv as select * from t1 start with id=141 connect by prior id=pid;
|
||||
228
src/test/regress/sql/sw_prepare.sql
Normal file
228
src/test/regress/sql/sw_prepare.sql
Normal file
@ -0,0 +1,228 @@
|
||||
drop schema if exists swtest cascade;
|
||||
create schema swtest;
|
||||
set current_schema=swtest;
|
||||
|
||||
drop table if exists swtest.test_area;
|
||||
drop table if exists swtest.test_area2;
|
||||
drop table if exists swtest.t1;
|
||||
drop table if exists swtest.t2;
|
||||
drop table if exists swtest.test_hcb_ptb;
|
||||
drop table if exists swtest.test_hcb_fqb;
|
||||
drop table if exists swtest.test_sublink;
|
||||
drop table if exists swtest.test_hcb_ptbc;
|
||||
drop table if exists swtest.test_swcb_a;
|
||||
drop table if exists swtest.trait_value;
|
||||
drop table if exists swtest.offers_20050701;
|
||||
drop table if exists swtest.brand;
|
||||
|
||||
create table swtest.test_area(id int4,name text, fatherid int4, name_desc text);
|
||||
insert into swtest.test_area values (1, '中国', 0, 'China');
|
||||
insert into swtest.test_area values (2, '湖南省',1 , 'Hunan');
|
||||
insert into swtest.test_area values (3, '广东省',1 , 'Guangdong');
|
||||
insert into swtest.test_area values (4, '海南省',1 , 'Hainan');
|
||||
insert into swtest.test_area values (5, '河北省',1 , 'Hebei');
|
||||
insert into swtest.test_area values (6, '河南省',1 , 'Henan');
|
||||
insert into swtest.test_area values (7, '山东省',1 , 'Shandong');
|
||||
insert into swtest.test_area values (8, '湖北省',1 , 'Hubei');
|
||||
insert into swtest.test_area values (9, '江苏省',1 , 'Jiangsu');
|
||||
insert into swtest.test_area values (10,'深圳市',3 , 'Shenzhen');
|
||||
insert into swtest.test_area values (11,'长沙市',2 , 'Changsha');
|
||||
insert into swtest.test_area values (22,'祁北县',13, 'Qibei');
|
||||
insert into swtest.test_area values (12,'南山区',10, 'Nanshan');
|
||||
insert into swtest.test_area values (21,'祁西县',13, 'Qixi');
|
||||
insert into swtest.test_area values (13,'衡阳市',2 , 'Hengyang');
|
||||
insert into swtest.test_area values (14,'耒阳市',13, 'Leiyang');
|
||||
insert into swtest.test_area values (15,'龙岗区',10, 'Longgang');
|
||||
insert into swtest.test_area values (16,'福田区',10, 'Futian');
|
||||
insert into swtest.test_area values (17,'宝安区',10, 'Baoan');
|
||||
insert into swtest.test_area values (19,'祁东县',13, 'Qidong');
|
||||
insert into swtest.test_area values (18,'常宁市',13, 'Changning');
|
||||
insert into swtest.test_area values (20,'祁南县',13, 'Qinan');
|
||||
|
||||
create table swtest.test_area2(id int4, id2 text, name text, fatherid int4, fatherid2 text, name_desc text);
|
||||
insert into swtest.test_area2 values (1, 'A', '中国', 0, '', 'China');
|
||||
insert into swtest.test_area2 values (2, 'B', '湖南省',1 , 'A', 'Hunan');
|
||||
insert into swtest.test_area2 values (3, 'C', '广东省',1 , 'A', 'Guangdong');
|
||||
insert into swtest.test_area2 values (4, 'D', '海南省',1 , 'A', 'Hainan');
|
||||
insert into swtest.test_area2 values (5, 'E', '河北省',1 , 'A', 'Hebei');
|
||||
insert into swtest.test_area2 values (6, 'F', '河南省',1 , 'A', 'Henan');
|
||||
insert into swtest.test_area2 values (7, 'G', '山东省',1 , 'A', 'Shandong');
|
||||
insert into swtest.test_area2 values (8, 'H', '湖北省',1 , 'A', 'Hubei');
|
||||
insert into swtest.test_area2 values (9, 'I', '江苏省',1 , 'A', 'Jiangsu');
|
||||
insert into swtest.test_area2 values (10, 'J', '深圳市',3 , 'C', 'Shenzhen');
|
||||
insert into swtest.test_area2 values (11, 'K', '长沙市',2 , 'B', 'Changsha');
|
||||
insert into swtest.test_area2 values (22, 'L', '祁北县',13, 'O', 'Qibei');
|
||||
insert into swtest.test_area2 values (12, 'M', '南山区',10, 'J', 'Nanshan');
|
||||
insert into swtest.test_area2 values (21, 'N', '祁西县',13, 'O', 'Qixi');
|
||||
insert into swtest.test_area2 values (13, 'O', '衡阳市',2 , 'B', 'Hengyang');
|
||||
insert into swtest.test_area2 values (14, 'P', '耒阳市',13, 'O', 'Leiyang');
|
||||
insert into swtest.test_area2 values (15, 'Q', '龙岗区',10, 'J', 'Longgang');
|
||||
insert into swtest.test_area2 values (16, 'R', '福田区',10, 'J', 'Futian');
|
||||
insert into swtest.test_area2 values (17, 'S', '宝安区',10, 'J', 'Baoan');
|
||||
insert into swtest.test_area2 values (19, 'T', '祁东县',13, 'O', 'Qidong');
|
||||
insert into swtest.test_area2 values (18, 'U', '常宁市',13, 'O', 'Changning');
|
||||
insert into swtest.test_area2 values (20, 'V', '祁南县',13, 'O', 'Qinan');
|
||||
|
||||
create table swtest.t1(id int, pid int, name text);
|
||||
insert into swtest.t1 values(1, 0, '1');
|
||||
insert into swtest.t1 values(2, 1, '2');
|
||||
insert into swtest.t1 values(3, 0, '3');
|
||||
insert into swtest.t1 values(4, 1, '4');
|
||||
insert into swtest.t1 values(5, 2, '5');
|
||||
insert into swtest.t1 values(6, 3, '6');
|
||||
insert into swtest.t1 values(7, 4, '7');
|
||||
insert into swtest.t1 values(8, 4, '8');
|
||||
insert into swtest.t1 values(9, 7, '9');
|
||||
|
||||
create table swtest.t2(id int, pid int, name text);
|
||||
insert into swtest.t2 values(1, 0, '1');
|
||||
insert into swtest.t2 values(2, 1, '2');
|
||||
insert into swtest.t2 values(3, 0, '3');
|
||||
insert into swtest.t2 values(4, 1, '4');
|
||||
insert into swtest.t2 values(5, 2, '5');
|
||||
insert into swtest.t2 values(6, 3, '6');
|
||||
insert into swtest.t2 values(7, 4, '7');
|
||||
insert into swtest.t2 values(8, 4, '8');
|
||||
insert into swtest.t2 values(9, 7, '9');
|
||||
|
||||
CREATE TABLE swtest.test_hcb_ptb(ID INT,CHA CHAR(10),VCH VARCHAR2(10),TEX TEXT,DAT DATE,TIM TIME,TIS TIMESTAMP,NAME VARCHAR2(80),PID INT,PCHA CHAR(10),PVCH VARCHAR2(10),PTEX TEXT,PDAT DATE,PTIM TIME,PTIS TIMESTAMP);
|
||||
CREATE TABLE swtest.TEST_HCB_FQB(ID INT,CHA CHAR(10),VCH VARCHAR2(10),TEX TEXT,DAT DATE,TIM TIME,TIS TIMESTAMP,NAME VARCHAR2(80),PID INT,PCHA CHAR(10),PVCH VARCHAR2(10),PTEX TEXT,PDAT DATE,PTIM TIME,PTIS TIMESTAMP);
|
||||
CREATE TABLE swtest.TEST_SUBLINK(ID INT,VCH VARCHAR2(10));
|
||||
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 1 , 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12' ,'中国' , 0, '0' , '0' , '0' , '2000-12-12 12:12:12', '00:00:01', '2000-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 11 , 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01' ,'江苏省', 1, 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 12 , 'ab' , 'ab' , 'ab' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01' ,'山东省', 1, 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 13 , 'ac' , 'ac' , 'ac' , '2021-01-01 01:01:02', '01:01:02', '2021-01-01 01:01:02' ,'安徽省', 1, 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 14 , 'ad' , 'ad' , 'ad' , '2021-01-01 01:01:03', '01:01:03', '2021-01-01 01:01:03' ,'河南省', 1, 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 15 , 'ae' , 'ae' , 'ae' , '2021-01-01 01:01:05', '01:01:05', '2021-01-01 01:01:05' ,'河北省', 1, 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 16 , 'af' , 'af' , 'af' , '2021-01-01 01:01:06', '01:01:06', '2021-01-01 01:01:06' ,'湖南省', 1, 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 17 , 'ag' , 'ag' , 'ag' , '2021-01-01 01:01:07', '01:01:07', '2021-01-01 01:01:07' ,'湖北省', 1, 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 18 , 'ah' , 'ah' , 'ah' , '2021-01-01 01:01:08', '01:01:08', '2021-01-01 01:01:08' ,'贵州省', 1, 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES( 19 , 'ai' , 'ai' , 'ai' , '2021-01-01 01:01:09', '01:01:09', '2021-01-01 01:01:09' ,'武汉省', 1, 'a' , 'a' , 'a' , '2021-12-12 12:12:12', '12:12:12', '2021-12-12 12:12:12');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(111 , 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10' ,'南京市', 11, 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(112 , 'aab', 'aab', 'aab', '2021-01-01 01:01:11', '01:01:11', '2021-01-01 01:01:11' ,'宿迁市', 11, 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(113 , 'aac', 'aac', 'aac', '2021-01-01 01:01:12', '01:01:12', '2021-01-01 01:01:12' ,'徐州市', 11, 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(114 , 'aad', 'aad', 'aad', '2021-01-01 01:01:13', '01:01:13', '2021-01-01 01:01:13' ,'苏州市', 11, 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(115 , 'aae', 'aae', 'aae', '2021-01-01 01:01:14', '01:01:14', '2021-01-01 01:01:14' ,'盐城市', 11, 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(116 , 'aaf', 'aaf', 'aaf', '2021-01-01 01:01:15', '01:01:15', '2021-01-01 01:01:15' ,'无锡市', 11, 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(117 , 'aag', 'aag', 'aag', '2021-01-01 01:01:16', '01:01:16', '2021-01-01 01:01:16' ,'常州市', 11, 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(118 , 'aah', 'aah', 'aah', '2021-01-01 01:01:17', '01:01:17', '2021-01-01 01:01:17' ,'连云港', 11, 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(119 , 'aai', 'aai', 'aai', '2021-01-01 01:01:18', '01:01:18', '2021-01-01 01:01:18' ,'泰州市', 11, 'aa' , 'aa' , 'aa' , '2021-01-01 01:01:01', '01:01:01', '2021-01-01 01:01:01');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(121 , 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20' ,'江宁区', 111, 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(122 , 'abb', 'abb', 'abb', '2021-01-01 01:01:21', '01:01:21', '2021-01-01 01:01:21' ,'雨花台', 111, 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(123 , 'abc', 'abc', 'abc', '2021-01-01 01:01:22', '01:01:22', '2021-01-01 01:01:22' ,'鼓楼区', 111, 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(124 , 'abd', 'abd', 'abd', '2021-01-01 01:01:23', '01:01:23', '2021-01-01 01:01:23' ,'玄武区', 111, 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(125 , 'abe', 'abe', 'abe', '2021-01-01 01:01:24', '01:01:24', '2021-01-01 01:01:24' ,'建邺区', 111, 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(126 , 'abf', 'abf', 'abf', '2021-01-01 01:01:25', '01:01:25', '2021-01-01 01:01:25' ,'秦淮区', 111, 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(127 , 'abg', 'abg', 'abg', '2021-01-01 01:01:26', '01:01:26', '2021-01-01 01:01:26' ,'浦口区', 111, 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(128 , 'abh', 'abh', 'abh', '2021-01-01 01:01:27', '01:01:27', '2021-01-01 01:01:27' ,'浦口区', 111, 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(129 , 'abi', 'abi', 'abi', '2021-01-01 01:01:28', '01:01:28', '2021-01-01 01:01:28' ,'六合区', 111, 'aaa', 'aaa', 'aaa', '2021-01-01 01:01:10', '01:01:10', '2021-01-01 01:01:10');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(131 , 'aca', 'aca', 'aca', '2021-01-01 01:01:30', '01:01:30', '2021-01-01 01:01:30' ,'东山街', 121, 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(132 , 'acb', 'acb', 'acb', '2021-01-01 01:01:31', '01:01:31', '2021-01-01 01:01:31' ,'秣陵街', 121, 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(133 , 'acc', 'acc', 'acc', '2021-01-01 01:01:32', '01:01:32', '2021-01-01 01:01:32' ,'汤山街', 121, 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(134 , 'acd', 'acd', 'acd', '2021-01-01 01:01:33', '01:01:33', '2021-01-01 01:01:33' ,'淳化街', 121, 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(135 , 'ace', 'ace', 'ace', '2021-01-01 01:01:34', '01:01:34', '2021-01-01 01:01:34' ,'禄口街', 121, 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(136 , 'acf', 'acf', 'acf', '2021-01-01 01:01:35', '01:01:35', '2021-01-01 01:01:35' ,'江宁街', 121, 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(137 , 'acg', 'acg', 'acg', '2021-01-01 01:01:36', '01:01:36', '2021-01-01 01:01:36' ,'谷里街', 121, 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(138 , 'ach', 'ach', 'ach', '2021-01-01 01:01:37', '01:01:37', '2021-01-01 01:01:37' ,'湖熟街', 121, 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20');
|
||||
INSERT INTO swtest.TEST_HCB_FQB VALUES(139 , 'aci', 'aci', 'aci', '2021-01-01 01:01:38', '01:01:38', '2021-01-01 01:01:38' ,'横溪街', 121, 'aba', 'aba', 'aba', '2021-01-01 01:01:20', '01:01:20', '2021-01-01 01:01:20');
|
||||
|
||||
insert into swtest.test_hcb_ptb values( 1,'a',' a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12','中国', 0,'0','0','0','2000-12-12 12:12:12','00:00:01','2000-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values( 11,'aa',' aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01','江苏省', 1,'a','a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values( 12,'ab',' ab','ab','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01','山东省', 1,'a','a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values( 13,'ac',' ac','ac','2021-01-01 01:01:02','01:01:02','2021-01-01 01:01:02','安徽省', 1,'a','a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values( 14,'ad',' ad','ad','2021-01-01 01:01:03','01:01:03','2021-01-01 01:01:03','河南省', 1,'a','a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values( 15,'ae',' ae','ae','2021-01-01 01:01:05','01:01:05','2021-01-01 01:01:05','河北省', 1,'a','a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values( 16,'af',' af','af','2021-01-01 01:01:06','01:01:06','2021-01-01 01:01:06','湖南省', 1,'a','a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values( 17,'ag',' ag','ag','2021-01-01 01:01:07','01:01:07','2021-01-01 01:01:07','湖北省', 1,'a','a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values( 18,'ah',' ah','ah','2021-01-01 01:01:08','01:01:08','2021-01-01 01:01:08','贵州省', 1,'a','a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values( 19,'ai',' ai','ai','2021-01-01 01:01:09','01:01:09','2021-01-01 01:01:09','武汉省', 1,'a','a','a','2021-12-12 12:12:12','12:12:12','2021-12-12 12:12:12' );
|
||||
insert into swtest.test_hcb_ptb values(111,'aaa',' aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10','南京市', 11,'aa','aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01' );
|
||||
insert into swtest.test_hcb_ptb values(112,'aab',' aab','aab','2021-01-01 01:01:11','01:01:11','2021-01-01 01:01:11','宿迁市', 11,'aa','aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01' );
|
||||
insert into swtest.test_hcb_ptb values(113,'aac',' aac','aac','2021-01-01 01:01:12','01:01:12','2021-01-01 01:01:12','徐州市', 11,'aa','aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01' );
|
||||
insert into swtest.test_hcb_ptb values(114,'aad',' aad','aad','2021-01-01 01:01:13','01:01:13','2021-01-01 01:01:13','苏州市', 11,'aa','aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01' );
|
||||
insert into swtest.test_hcb_ptb values(115,'aae',' aae','aae','2021-01-01 01:01:14','01:01:14','2021-01-01 01:01:14','盐城市', 11,'aa','aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01' );
|
||||
insert into swtest.test_hcb_ptb values(117,'aag',' aag','aag','2021-01-01 01:01:16','01:01:16','2021-01-01 01:01:16','常州市', 11,'aa','aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01' );
|
||||
insert into swtest.test_hcb_ptb values(116,'aaf',' aaf','aaf','2021-01-01 01:01:15','01:01:15','2021-01-01 01:01:15','无锡市', 11,'aa','aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01' );
|
||||
insert into swtest.test_hcb_ptb values(118,'aah',' aah','aah','2021-01-01 01:01:17','01:01:17','2021-01-01 01:01:17','连云港', 11,'aa','aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01' );
|
||||
insert into swtest.test_hcb_ptb values(119,'aai',' aai','aai','2021-01-01 01:01:18','01:01:18','2021-01-01 01:01:18','泰州市', 11,'aa','aa','aa','2021-01-01 01:01:01','01:01:01','2021-01-01 01:01:01' );
|
||||
insert into swtest.test_hcb_ptb values(121,'aba',' aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20','江宁区', 111,'aaa','aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10' );
|
||||
insert into swtest.test_hcb_ptb values(122,'abb',' abb','abb','2021-01-01 01:01:21','01:01:21','2021-01-01 01:01:21','雨花台', 111,'aaa','aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10' );
|
||||
insert into swtest.test_hcb_ptb values(123,'abc',' abc','abc','2021-01-01 01:01:22','01:01:22','2021-01-01 01:01:22','鼓楼区', 111,'aaa','aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10' );
|
||||
insert into swtest.test_hcb_ptb values(124,'abd',' abd','abd','2021-01-01 01:01:23','01:01:23','2021-01-01 01:01:23','玄武区', 111,'aaa','aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10' );
|
||||
insert into swtest.test_hcb_ptb values(125,'abe',' abe','abe','2021-01-01 01:01:24','01:01:24','2021-01-01 01:01:24','建邺区', 111,'aaa','aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10' );
|
||||
insert into swtest.test_hcb_ptb values(126,'abf',' abf','abf','2021-01-01 01:01:25','01:01:25','2021-01-01 01:01:25','秦淮区', 111,'aaa','aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10' );
|
||||
insert into swtest.test_hcb_ptb values(127,'abg',' abg','abg','2021-01-01 01:01:26','01:01:26','2021-01-01 01:01:26','浦口区', 111,'aaa','aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10' );
|
||||
insert into swtest.test_hcb_ptb values(128,'abh',' abh','abh','2021-01-01 01:01:27','01:01:27','2021-01-01 01:01:27','浦口区', 111,'aaa','aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10' );
|
||||
insert into swtest.test_hcb_ptb values(129,'abi',' abi','abi','2021-01-01 01:01:28','01:01:28','2021-01-01 01:01:28','六合区', 111,'aaa','aaa','aaa','2021-01-01 01:01:10','01:01:10','2021-01-01 01:01:10' );
|
||||
insert into swtest.test_hcb_ptb values(131,'aca',' aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30','东山街', 121,'aba','aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20' );
|
||||
insert into swtest.test_hcb_ptb values(132,'acb',' acb','acb','2021-01-01 01:01:31','01:01:31','2021-01-01 01:01:31','秣陵街', 121,'aba','aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20' );
|
||||
insert into swtest.test_hcb_ptb values(133,'acc',' acc','acc','2021-01-01 01:01:32','01:01:32','2021-01-01 01:01:32','汤山街', 121,'aba','aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20' );
|
||||
insert into swtest.test_hcb_ptb values(135,'ace',' ace','ace','2021-01-01 01:01:34','01:01:34','2021-01-01 01:01:34','禄口街', 121,'aba','aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20' );
|
||||
insert into swtest.test_hcb_ptb values(134,'acd',' acd','acd','2021-01-01 01:01:33','01:01:33','2021-01-01 01:01:33','淳化街', 121,'aba','aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20' );
|
||||
insert into swtest.test_hcb_ptb values(136,'acf',' acf','acf','2021-01-01 01:01:35','01:01:35','2021-01-01 01:01:35','江宁街', 121,'aba','aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20' );
|
||||
insert into swtest.test_hcb_ptb values(137,'acg',' acg','acg','2021-01-01 01:01:36','01:01:36','2021-01-01 01:01:36','谷里街', 121,'aba','aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20' );
|
||||
insert into swtest.test_hcb_ptb values(138,'ach',' ach','ach','2021-01-01 01:01:37','01:01:37','2021-01-01 01:01:37','湖熟街', 121,'aba','aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20' );
|
||||
insert into swtest.test_hcb_ptb values(139,'aci',' aci','aci','2021-01-01 01:01:38','01:01:38','2021-01-01 01:01:38','横溪街', 121,'aba','aba','aba','2021-01-01 01:01:20','01:01:20','2021-01-01 01:01:20' );
|
||||
insert into swtest.test_hcb_ptb values(141,'ada',' ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40','江南摩卡', 131,'aca','aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30' );
|
||||
insert into swtest.test_hcb_ptb values(142,'adb',' adb','adb','2021-01-01 01:01:41','01:01:41','2021-01-01 01:01:41','四季云顶', 131,'aca','aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30' );
|
||||
insert into swtest.test_hcb_ptb values(143,'adc',' adc','adc','2021-01-01 01:01:42','01:01:42','2021-01-01 01:01:42','盛世江南', 131,'aca','aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30' );
|
||||
insert into swtest.test_hcb_ptb values(144,'add',' add','add','2021-01-01 01:01:43','01:01:43','2021-01-01 01:01:43','七里香都', 131,'aca','aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30' );
|
||||
insert into swtest.test_hcb_ptb values(145,'ade',' ade','ade','2021-01-01 01:01:44','01:01:44','2021-01-01 01:01:44','西山枫林', 131,'aca','aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30' );
|
||||
insert into swtest.test_hcb_ptb values(146,'adf',' adf','adf','2021-01-01 01:01:45','01:01:45','2021-01-01 01:01:45','醉墨小镇', 131,'aca','aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30' );
|
||||
insert into swtest.test_hcb_ptb values(147,'adg',' adg','adg','2021-01-01 01:01:46','01:01:46','2021-01-01 01:01:46','布拉格调', 131,'aca','aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30' );
|
||||
insert into swtest.test_hcb_ptb values(148,'adh',' adh','adh','2021-01-01 01:01:47','01:01:47','2021-01-01 01:01:47','清幽别院', 131,'aca','aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30' );
|
||||
insert into swtest.test_hcb_ptb values(149,'adi',' adi','adi','2021-01-01 01:01:48','01:01:48','2021-01-01 01:01:48','璀璨天城', 131,'aca','aca','aca','2021-01-01 01:01:30','01:01:30','2021-01-01 01:01:30' );
|
||||
insert into swtest.test_hcb_ptb values(151,'aea',' aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50','江南一楼', 141,'ada','ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40' );
|
||||
insert into swtest.test_hcb_ptb values(152,'aeb',' aeb','aeb','2021-01-01 01:01:51','01:01:51','2021-01-01 01:01:51','江南二楼', 141,'ada','ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40' );
|
||||
insert into swtest.test_hcb_ptb values(153,'aec',' aec','aec','2021-01-01 01:01:52','01:01:52','2021-01-01 01:01:52','江南三楼', 141,'ada','ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40' );
|
||||
insert into swtest.test_hcb_ptb values(154,'aed',' aed','aed','2021-01-01 01:01:53','01:01:53','2021-01-01 01:01:53','江南四楼', 141,'ada','ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40' );
|
||||
insert into swtest.test_hcb_ptb values(155,'aee',' aee','aee','2021-01-01 01:01:54','01:01:54','2021-01-01 01:01:54','江南五楼', 141,'ada','ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40' );
|
||||
insert into swtest.test_hcb_ptb values(156,'aef',' aef','aef','2021-01-01 01:01:55','01:01:55','2021-01-01 01:01:55','江南六楼', 141,'ada','ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40' );
|
||||
insert into swtest.test_hcb_ptb values(157,'aeg',' aeg','aeg','2021-01-01 01:01:56','01:01:56','2021-01-01 01:01:56','江南七楼', 141,'ada','ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40' );
|
||||
insert into swtest.test_hcb_ptb values(158,'aeh',' aeh','aeh','2021-01-01 01:01:57','01:01:57','2021-01-01 01:01:57','江南八楼', 141,'ada','ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40' );
|
||||
insert into swtest.test_hcb_ptb values(159,'aei',' aei','aei','2021-01-01 01:01:58','01:01:58','2021-01-01 01:01:58','江南九楼', 141,'ada','ada','ada','2021-01-01 01:01:40','01:01:40','2021-01-01 01:01:40' );
|
||||
insert into swtest.test_hcb_ptb values(161,'afa',' afa','afa','2021-01-01 01:02:50','01:02:50','2021-01-01 01:02:50','第一单元', 151,'aea','aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50' );
|
||||
insert into swtest.test_hcb_ptb values(162,'afb',' afb','afb','2021-01-01 01:02:51','01:02:51','2021-01-01 01:02:51','第二单元', 151,'aea','aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50' );
|
||||
insert into swtest.test_hcb_ptb values(163,'afc',' afc','afc','2021-01-01 01:02:52','01:02:52','2021-01-01 01:02:52','第三单元', 151,'aea','aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50' );
|
||||
insert into swtest.test_hcb_ptb values(164,'afd',' afd','afd','2021-01-01 01:02:53','01:02:53','2021-01-01 01:02:53','第四单元', 151,'aea','aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50' );
|
||||
insert into swtest.test_hcb_ptb values(165,'afe',' afe','afe','2021-01-01 01:02:54','01:02:54','2021-01-01 01:02:54','第五单元', 151,'aea','aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50' );
|
||||
insert into swtest.test_hcb_ptb values(166,'aff',' aff','aff','2021-01-01 01:02:55','01:02:55','2021-01-01 01:02:55','第六单元', 151,'aea','aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50' );
|
||||
insert into swtest.test_hcb_ptb values(167,'afg',' afg','afg','2021-01-01 01:02:56','01:02:56','2021-01-01 01:02:56','第七单元', 151,'aea','aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50' );
|
||||
insert into swtest.test_hcb_ptb values(168,'afh',' afh','afh','2021-01-01 01:02:57','01:02:57','2021-01-01 01:02:57','第八单元', 151,'aea','aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50' );
|
||||
insert into swtest.test_hcb_ptb values(169,'afi',' afi','afi','2021-01-01 01:02:58','01:02:58','2021-01-01 01:02:58','第九单元', 151,'aea','aea','aea','2021-01-01 01:01:50','01:01:50','2021-01-01 01:01:50' );
|
||||
|
||||
CREATE TABLE swtest.test_hcb_ptbc(ID INT,CHA CHAR(10),VCH VARCHAR2(10),TEX TEXT,DAT DATE,TIM TIME,TIS TIMESTAMP,NAME VARCHAR2(80),PID INT,PCHA CHAR(10),PVCH VARCHAR2(10),PTEX TEXT,PDAT DATE,PTIM TIME,PTIS TIMESTAMP
|
||||
) with (orientation = column);
|
||||
insert into test_hcb_ptbc select * from test_hcb_ptb;
|
||||
|
||||
CREATE TABLE swtest.test_swcb_a (ID varchar2(10) PRIMARY KEY,NAME varchar2(100),PID varchar2(10));
|
||||
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00001', '中国', '-1');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00011', '陕西', '00001');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00012', '贵州', '00001');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00013', '河南', '00001');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00111', '西安', '00011');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00112', '咸阳', '00011');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00113', '延安', '00011');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00114', '华县', '00013');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00115', '河内', '00016');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00116', '清迈', '00015');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00117', '仰光', '00017');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00118', '纽约', '00120');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00119', '费城', '00118');
|
||||
INSERT INTO swtest.test_swcb_a VALUES ('00120', '华盛顿', '00119');
|
||||
|
||||
create table swtest.trait_value(TRAIT_VALUE_CD VARCHAR(50)primary key, TRAIT_VALUE_DESC VARCHAR(250) NULL, TRAIT_VAL VARCHAR(100) NULL, UOM_CD VARCHAR(50) NULL, TRAIT_CD VARCHAR(50) NULL,c1 serial);
|
||||
|
||||
INSERT INTO swtest.TRAIT_VALUE VALUES ('A', NULL, 'A' , 'A' , 'A');
|
||||
INSERT INTO swtest.TRAIT_VALUE VALUES ('B', 'B' , NULL, 'B' , 'B');
|
||||
INSERT INTO swtest.TRAIT_VALUE VALUES ('C', 'C' , 'C' , NULL, NULL);
|
||||
INSERT INTO swtest.TRAIT_VALUE VALUES ('D', NULL, NULL, NULL, 'D');
|
||||
INSERT INTO swtest.TRAIT_VALUE VALUES ('E', 'E' , ' AA' , 'E' , 'E');
|
||||
INSERT INTO swtest.TRAIT_VALUE VALUES ('F', ' ' , 'AA ' , 'F' , 'F');
|
||||
|
||||
create table swtest.offers_20050701(PROMO_ID VARCHAR(10), PARTY_ID VARCHAR(10) NULL, LOCATION_ID number(17,0) NULL);
|
||||
create table swtest.brand(a int default 2, mfg varchar(500), brand_cd varchar(500), brand_name varchar(100), brand_party_id number(18,10) NULL);
|
||||
|
||||
analyze;
|
||||
169
src/test/regress/sql/sw_siblings.sql
Normal file
169
src/test/regress/sql/sw_siblings.sql
Normal file
@ -0,0 +1,169 @@
|
||||
set client_min_messages = error;
|
||||
set search_path=swtest;
|
||||
SET CLIENT_ENCODING='UTF8';
|
||||
|
||||
/*
|
||||
*
|
||||
* START WITH .... CONNECT BY基础测试用例
|
||||
*
|
||||
* 测试用例表数
|
||||
* openGauss=# select * from swtest.test_area;
|
||||
* id | name | fatherid | name_desc
|
||||
* ----+--------+----------+-----------
|
||||
* 1 | 中国 | 0 | china
|
||||
* 2 | 湖南省 | 1 | hunan
|
||||
* 3 | 广东省 | 1 | guangdong
|
||||
* 4 | 海南省 | 1 | hainan
|
||||
* 5 | 河北省 | 1 | hebei
|
||||
* 6 | 河南省 | 1 | henan
|
||||
* 7 | 山东省 | 1 | shandong
|
||||
* 8 | 湖北省 | 1 | hubei
|
||||
* 9 | 江苏省 | 1 | jiangsu
|
||||
* 10 | 深圳市 | 3 | shenzhen
|
||||
* 11 | 长沙市 | 2 | changsha
|
||||
* 22 | 祁北县 | 13 | qibei
|
||||
* 12 | 南山区 | 10 | nanshan
|
||||
* 21 | 祁西县 | 13 | qixi
|
||||
* 13 | 衡阳市 | 2 | hengyang
|
||||
* 14 | 耒阳市 | 13 | leiyang
|
||||
* 15 | 龙岗区 | 10 | longgang
|
||||
* 16 | 福田区 | 10 | futian
|
||||
* 17 | 宝安区 | 10 | baoan
|
||||
* 19 | 祁东县 | 13 | qidong
|
||||
* 18 | 常宁市 | 13 | changning
|
||||
* 20 | 祁南县 | 13 | qinan
|
||||
*
|
||||
*/
|
||||
|
||||
/* case 1.1 test root->leaf order siblings by id asc
|
||||
* expect order: 1 2 11 13 14 18 19 20 21 22 3 10 12 15 16 17 4 5 6 7 8 9
|
||||
*/
|
||||
EXPLAIN (costs off)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id;
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id;
|
||||
|
||||
/* case 1.2 test root->leaf order siblings by id desc
|
||||
* expect order: 1 9 8 7 6 5 4 3 10 17 16 15 12 2 13 22 21 20 19 18 14 11
|
||||
*/
|
||||
EXPLAIN (costs off)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id desc;
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id desc;
|
||||
|
||||
/* case 1.3 test double_root->leaf order siblings by id asc
|
||||
* expect order: 10 12 15 16 17 13 14 18 19 20 21 22
|
||||
*/
|
||||
EXPLAIN (costs off)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '衡阳市' or name = '深圳市'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id;
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '衡阳市' or name = '深圳市'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id;
|
||||
|
||||
/* case 1.4 test double_root->leaf order siblings by id desc
|
||||
* expect order: 13 22 21 20 19 18 14 10 17 16 15 12
|
||||
*/
|
||||
EXPLAIN (costs off)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '衡阳市' or name = '深圳市'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id desc;
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '衡阳市' or name = '深圳市'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id desc;
|
||||
|
||||
|
||||
/* case 1.5 test leaf->root order siblings by id asc
|
||||
* expect order: 18 13 2 1
|
||||
*/
|
||||
EXPLAIN (costs off)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '常宁市'
|
||||
CONNECT BY id = prior fatherid
|
||||
ORDER SIBLINGS BY id;
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '常宁市'
|
||||
CONNECT BY id = prior fatherid
|
||||
ORDER SIBLINGS BY id;
|
||||
|
||||
/* case 1.6 test leaf->root order siblings by id desc
|
||||
* expect order: 18 13 2 1
|
||||
*/
|
||||
EXPLAIN (costs off)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '常宁市'
|
||||
CONNECT BY id = prior fatherid
|
||||
ORDER SIBLINGS BY id desc;
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '常宁市'
|
||||
CONNECT BY id = prior fatherid
|
||||
ORDER SIBLINGS BY id desc;
|
||||
|
||||
/* case 1.7
|
||||
* test order siblings by const
|
||||
* expect order: 1 2 11 13 14 18 19 20 21 22 3 10 12 15 16 17 4 5 6 7 8 9
|
||||
*/
|
||||
EXPLAIN (costs off)
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY 1;
|
||||
|
||||
SELECT *, LEVEL, connect_by_isleaf, connect_by_iscycle, connect_by_root(name_desc), SYS_CONNECT_BY_PATH(name, '@') cpath
|
||||
FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY 1;
|
||||
|
||||
/* case 1.8++ test explain for multiple order siblings column */
|
||||
EXPLAIN (costs off)
|
||||
SELECT * FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id, name, name_desc;
|
||||
|
||||
EXPLAIN (costs off)
|
||||
SELECT * FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id desc, name desc , name_desc desc;
|
||||
|
||||
EXPLAIN (costs off)
|
||||
SELECT * FROM test_area
|
||||
START WITH name = '中国'
|
||||
CONNECT BY prior id = fatherid
|
||||
ORDER SIBLINGS BY id desc, name, name_desc desc;
|
||||
Reference in New Issue
Block a user