!4887 兼容B库下null值的分区问题

Merge pull request !4887 from 吴岳川/master
This commit is contained in:
opengauss_bot
2024-03-05 08:46:38 +00:00
committed by Gitee
16 changed files with 508 additions and 80 deletions

View File

@ -385,9 +385,9 @@ void partitionKeyCompareForRouting(Const **partkey_value, Const **partkey_bound,
ereport(ERROR, (errcode(ERRCODE_UNEXPECTED_NULL_VALUE),
errmsg("null value can not be compared with null value.")));
} else if (kv->constisnull) {
compare = 1;
compare = DB_IS_CMPT(B_FORMAT) ? -1 : 1;
} else {
compare = -1;
compare = DB_IS_CMPT(B_FORMAT) ? 1 : -1;
}
break;
}

View File

@ -556,6 +556,8 @@ List* build_index_pathkeys(PlannerInfo* root, IndexOptInfo* index, ScanDirection
/* We assume we don't need to make a copy of the tlist item */
indexkey = indextle->expr;
if (ScanDirectionIsBackward(scandir)) {
reverse_sort = !index->reverse_sort[i];
nulls_first = !index->nulls_first[i];
@ -563,6 +565,17 @@ List* build_index_pathkeys(PlannerInfo* root, IndexOptInfo* index, ScanDirection
reverse_sort = index->reverse_sort[i];
nulls_first = index->nulls_first[i];
}
/*
* in B format, null value in insert into the minimal partition
* if index is default nulls last, set to nulls first
* if index is nulls first, dothing
* */
if (index->ispartitionedindex && !index->isGlobal && DB_IS_CMPT(B_FORMAT)) {
if (!index->nulls_first[i]) {
nulls_first = !nulls_first;
}
}
/* OK, try to make a canonical pathkey for this sort key */
cpathkey = make_pathkey_from_sortinfo(root,

View File

@ -1112,7 +1112,8 @@ explain(costs off) insert /*+ ignore_error */ into t_not_null_key_partition val
(3 rows)
insert /*+ ignore_error */ into t_not_null_key_partition values (null);
WARNING: inserted partition key does not map to any table partition
WARNING: null value in column "num" violates not-null constraint
DETAIL: Failing row contains (null, null).
select * from t_not_null_key_partition;
num | ca_city
-----+----------

View File

@ -269,9 +269,9 @@ select cast('s' as int);
--------------- limit #,#-------------------
-- limit case in postgresql
\c regression
create table test(a int);
insert into test values (1),(2),(3),(4),(5);
select * from test order by 1 limit 2,3;
create table test_limit_table(a int);
insert into test_limit_table values (1),(2),(3),(4),(5);
select * from test_limit_table order by 1 limit 2,3;
a
---
3
@ -279,7 +279,7 @@ select * from test order by 1 limit 2,3;
5
(3 rows)
select * from test order by 1 limit 2,6;
select * from test_limit_table order by 1 limit 2,6;
a
---
3
@ -287,17 +287,17 @@ select * from test order by 1 limit 2,6;
5
(3 rows)
select * from test order by 1 limit 6,2;
select * from test_limit_table order by 1 limit 6,2;
a
---
(0 rows)
drop table test;
drop table test_limit_table;
-- limit case in B db
\c B_db
create table test(a int);
insert into test values (1),(2),(3),(4),(5);
select * from test order by 1 limit 2,3;
create table test_limit_table(a int);
insert into test_limit_table values (1),(2),(3),(4),(5);
select * from test_limit_table order by 1 limit 2,3;
a
---
3
@ -305,7 +305,7 @@ select * from test order by 1 limit 2,3;
5
(3 rows)
select * from test order by 1 limit 2,6;
select * from test_limit_table order by 1 limit 2,6;
a
---
3
@ -313,12 +313,12 @@ select * from test order by 1 limit 2,6;
5
(3 rows)
select * from test order by 1 limit 6,2;
select * from test_limit_table order by 1 limit 6,2;
a
---
(0 rows)
drop table test;
drop table test_limit_table;
--------------timestampdiff-----------------
-- timestamp with time zone
-- timestamp1 > timestamp2

View File

@ -0,0 +1,289 @@
create database null_in_partition_a dbcompatibility 'a';
\c null_in_partition_a
create table base_partition_tbl
(
num int,
data1 text
) partition by range (num) (
partition num1 values less than (10),
partition num2 values less than (20),
partition num3 values less than (30),
partition num4 values less than (MAXVALUE)
);
insert into base_partition_tbl values(null, 'test');
select * from base_partition_tbl partition (num1);
num | data1
-----+-------
(0 rows)
select * from base_partition_tbl partition (num4);
num | data1
-----+-------
| test
(1 row)
create table base_partition_tbl_sub_partition
(
num int,
data1 text
)
partition by range (num) SUBPARTITION BY RANGE (num) (
partition num1 values less than (10)
(
SUBPARTITION num1_1 VALUES LESS THAN( 5 ),
SUBPARTITION num1_2 VALUES LESS THAN( 10 )
),
partition num2 values less than (20) (
SUBPARTITION num2_1 VALUES LESS THAN( 15 ),
SUBPARTITION num2_2 VALUES LESS THAN( 20 )
),
partition num3 values less than (30) (
SUBPARTITION num3_1 VALUES LESS THAN( 25 ),
SUBPARTITION num4_2 VALUES LESS THAN( 30 )
),
partition num4 values less than (MAXVALUE)
(
SUBPARTITION num4_1 VALUES LESS THAN( 35 ),
SUBPARTITION num5_2 VALUES LESS THAN( MAXVALUE )
)
);
insert into base_partition_tbl_sub_partition values(null, 'test');
select * from base_partition_tbl_sub_partition subpartition (num1_1);
num | data1
-----+-------
(0 rows)
select * from base_partition_tbl_sub_partition subpartition (num5_2);
num | data1
-----+-------
| test
(1 row)
create table t_range (c1 int, c2 int) partition by range(c1) (partition p1 values less than (10), partition p2 values less than(maxvalue));
insert into t_range values(null),(5),(100);
create index t_range_c1_idx on t_range (c1 nulls last) local;
explain (costs off) select /*+ indexscan(t_range) */* from t_range order by c1 nulls first; -- NO INDEX
WARNING: unused hint: IndexScan(t_range)
QUERY PLAN
---------------------------------------------
Sort
Sort Key: c1 NULLS FIRST
-> Partition Iterator
Iterations: 2
-> Partitioned Seq Scan on t_range
Selected Partitions: 1..2
(6 rows)
explain (costs off) select /*+ indexscan(t_range) */* from t_range order by c1 nulls last; -- INDEX
QUERY PLAN
--------------------------------------------------------------
Partition Iterator
Iterations: 2
-> Partitioned Index Scan using t_range_c1_idx on t_range
Selected Partitions: 1..2
(4 rows)
select /*+ indexscan(t_range) */* from t_range order by c1 nulls first; -- NO INDEX
c1 | c2
-----+----
|
5 |
100 |
(3 rows)
select /*+ indexscan(t_range) */* from t_range order by c1 nulls last; -- INDEX
c1 | c2
-----+----
5 |
100 |
|
(3 rows)
drop index t_range_c1_idx;
create index on t_range (c1 nulls first) local;
explain (costs off) select /*+ indexscan(t_range) */* from t_range order by c1 nulls first; -- INDEX
QUERY PLAN
--------------------------------------------------------------------
Sort
Sort Key: c1 NULLS FIRST
-> Partition Iterator
Iterations: 2
-> Partitioned Index Scan using t_range_c1_idx on t_range
Selected Partitions: 1..2
(6 rows)
explain (costs off) select /*+ indexscan(t_range) */* from t_range order by c1 nulls last; -- NO INDEX
WARNING: unused hint: IndexScan(t_range)
QUERY PLAN
---------------------------------------------
Sort
Sort Key: c1
-> Partition Iterator
Iterations: 2
-> Partitioned Seq Scan on t_range
Selected Partitions: 1..2
(6 rows)
select /*+ indexscan(t_range) */* from t_range order by c1 nulls first; -- INDEX
c1 | c2
-----+----
|
5 |
100 |
(3 rows)
select /*+ indexscan(t_range) */* from t_range order by c1 nulls last; -- NO INDEX
c1 | c2
-----+----
5 |
100 |
|
(3 rows)
create database null_in_partition_b dbcompatibility 'b';
\c null_in_partition_b
create table base_partition_tbl
(
num int,
data1 text
) partition by range (num) (
partition num1 values less than (10),
partition num2 values less than (20),
partition num3 values less than (30),
partition num4 values less than (MAXVALUE)
);
insert into base_partition_tbl values(null, 'test');
select * from base_partition_tbl partition (num1);
num | data1
-----+-------
| test
(1 row)
select * from base_partition_tbl partition (num4);
num | data1
-----+-------
(0 rows)
create table base_partition_tbl_sub_partition
(
num int,
data1 text
)
partition by range (num) SUBPARTITION BY RANGE (num) (
partition num1 values less than (10)
(
SUBPARTITION num1_1 VALUES LESS THAN( 5 ),
SUBPARTITION num1_2 VALUES LESS THAN( 10 )
),
partition num2 values less than (20) (
SUBPARTITION num2_1 VALUES LESS THAN( 15 ),
SUBPARTITION num2_2 VALUES LESS THAN( 20 )
),
partition num3 values less than (30) (
SUBPARTITION num3_1 VALUES LESS THAN( 25 ),
SUBPARTITION num4_2 VALUES LESS THAN( 30 )
),
partition num4 values less than (MAXVALUE)
(
SUBPARTITION num4_1 VALUES LESS THAN( 35 ),
SUBPARTITION num5_2 VALUES LESS THAN( MAXVALUE )
)
);
insert into base_partition_tbl_sub_partition values(null, 'test');
select * from base_partition_tbl_sub_partition subpartition (num1_1);
num | data1
-----+-------
| test
(1 row)
select * from base_partition_tbl_sub_partition subpartition (num5_2);
num | data1
-----+-------
(0 rows)
create table t_range (c1 int, c2 int) partition by range(c1) (partition p1 values less than (10), partition p2 values less than(maxvalue));
insert into t_range values(null),(5),(100);
create index t_range_c1_idx on t_range (c1 nulls last) local;
explain (costs off) select /*+ indexscan(t_range) */* from t_range order by c1 nulls first; -- INDEX
QUERY PLAN
--------------------------------------------------------------------
Sort
Sort Key: c1 NULLS FIRST
-> Partition Iterator
Iterations: 2
-> Partitioned Index Scan using t_range_c1_idx on t_range
Selected Partitions: 1..2
(6 rows)
explain (costs off) select /*+ indexscan(t_range) */* from t_range order by c1 nulls last; -- NO INDEX
WARNING: unused hint: IndexScan(t_range)
QUERY PLAN
---------------------------------------------
Sort
Sort Key: c1
-> Partition Iterator
Iterations: 2
-> Partitioned Seq Scan on t_range
Selected Partitions: 1..2
(6 rows)
select /*+ indexscan(t_range) */* from t_range order by c1 nulls first; -- INDEX
c1 | c2
-----+----
|
5 |
100 |
(3 rows)
select /*+ indexscan(t_range) */* from t_range order by c1 nulls last; -- NO INDEX
c1 | c2
-----+----
5 |
100 |
|
(3 rows)
drop index t_range_c1_idx;
create index on t_range (c1 nulls first) local;
explain (costs off) select /*+ indexscan(t_range) */* from t_range order by c1 nulls first; -- INDEX
QUERY PLAN
--------------------------------------------------------------------
Sort
Sort Key: c1 NULLS FIRST
-> Partition Iterator
Iterations: 2
-> Partitioned Index Scan using t_range_c1_idx on t_range
Selected Partitions: 1..2
(6 rows)
explain (costs off) select /*+ indexscan(t_range) */* from t_range order by c1 nulls last; -- NO INDEX
WARNING: unused hint: IndexScan(t_range)
QUERY PLAN
---------------------------------------------
Sort
Sort Key: c1
-> Partition Iterator
Iterations: 2
-> Partitioned Seq Scan on t_range
Selected Partitions: 1..2
(6 rows)
select /*+ indexscan(t_range) */* from t_range order by c1 nulls first; -- INDEX
c1 | c2
-----+----
|
5 |
100 |
(3 rows)
select /*+ indexscan(t_range) */* from t_range order by c1 nulls last; -- NO INDEX
c1 | c2
-----+----
5 |
100 |
|
(3 rows)
\c regression
drop database null_in_partition_a;
drop database null_in_partition_b;

View File

@ -1684,15 +1684,17 @@ select * from t_multi_parts_order partition (pd) order by col limit 10;
(10 rows)
rollback;
explain delete from t_multi_parts_order partition(pd, p1) order by col limit 10;
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------
Delete on t_multi_parts_order (cost=0.00..0.45 rows=10 width=14)
-> Partition Iterator (cost=0.00..108.28 rows=2402 width=14)
Iterations: 2
-> Partitioned Index Scan using tbl_idx_t_multi_parts_order on t_multi_parts_order (cost=0.00..108.28 rows=2402 width=14)
Selected Partitions: 1..2
(5 rows)
explain (costs off) delete from t_multi_parts_order partition(pd, p1) order by col limit 10;
QUERY PLAN
---------------------------------------------------------------
Delete on t_multi_parts_order
-> Sort
Sort Key: col
-> Partition Iterator
Iterations: 2
-> Partitioned Seq Scan on t_multi_parts_order
Selected Partitions: 1..2
(7 rows)
begin;
delete from t_multi_parts_order partition(p1, pd) order by col desc limit 10;
@ -1758,15 +1760,17 @@ select * from t_multi_parts_order partition (pd) order by col desc limit 10;
(10 rows)
rollback;
explain delete from t_multi_parts_order partition(pd, p1) order by col desc limit 10;
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------------------------
Delete on t_multi_parts_order (cost=0.00..0.45 rows=10 width=14)
-> Partition Iterator Scan Backward (cost=0.00..108.28 rows=2402 width=14)
Iterations: 2
-> Partitioned Index Scan Backward using tbl_idx_t_multi_parts_order on t_multi_parts_order (cost=0.00..108.28 rows=2402 width=14)
Selected Partitions: 1..2
(5 rows)
explain (costs off) delete from t_multi_parts_order partition(pd, p1) order by col desc limit 10;
QUERY PLAN
---------------------------------------------------------------
Delete on t_multi_parts_order
-> Sort
Sort Key: col DESC
-> Partition Iterator
Iterations: 2
-> Partitioned Seq Scan on t_multi_parts_order
Selected Partitions: 1..2
(7 rows)
drop table if exists t_multi_parts_order;
-- range partitions with global index, single column

View File

@ -1,26 +1,25 @@
--
-- SUBSELECT TEST
-- 子查询可以出现在目标列、FROM子句、WHERE子句、JOIN/ON子句、GROUPBY子句、HAVING子句、ORDERBY子句等位置。
--
create table test_tbl1 (f1 numeric);
insert into test_tbl1 values (1), (1.000000000000000000001), (2), (3);
create table test_tbl2 (f2 float8);
insert into test_tbl2 values (1), (2), (3);
select * from test_tbl2
where f2 in (select f1 from test_tbl1)
ORDER BY f2;
f2
-----------
1
2
3
----
1
2
3
(3 rows)
select * from test_tbl1
where f1 in (select f2 from test_tbl2)
ORDER BY f1;
f1
f1
-------------------------
1
1.000000000000000000001
@ -28,7 +27,6 @@ select * from test_tbl1
3
(4 rows)
DROP TABLE IF EXISTS test_table;
NOTICE: table "test_table" does not exist, skipping
CREATE TABLE test_table (f1 int, f2 date);

View File

@ -127,7 +127,7 @@ select rownum, name, address, age from rownum_table where address = 'xian' or ro
------------------
--test order by
--create test table
create table test_table
create table test_table_on_rownum
(
id integer primary key ,
name varchar2(20) ,
@ -135,16 +135,16 @@ create table test_table
address varchar2(20) not null,
tele varchar2(20) default '101'
);
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "test_table_pkey" for table "test_table"
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "test_table_on_rownum_pkey" for table "test_table_on_rownum"
--insert data
insert into test_table values(1,'charlie', 40, 'shanghai');
insert into test_table values(2,'lincon', 10, 'xianyang');
insert into test_table values(3,'charlie', 40, 'chengdu');
insert into test_table values(4,'lincon', 10, 'xian', '');
insert into test_table values(5,'charlie', 40, 'chengdu');
insert into test_table values(6,'lincon', 10, 'xian', '12345657');
insert into test_table_on_rownum values(1,'charlie', 40, 'shanghai');
insert into test_table_on_rownum values(2,'lincon', 10, 'xianyang');
insert into test_table_on_rownum values(3,'charlie', 40, 'chengdu');
insert into test_table_on_rownum values(4,'lincon', 10, 'xian', '');
insert into test_table_on_rownum values(5,'charlie', 40, 'chengdu');
insert into test_table_on_rownum values(6,'lincon', 10, 'xian', '12345657');
--test order by
select * from (select * from test_table order by id) as result where rownum < 4;
select * from (select * from test_table_on_rownum order by id) as result where rownum < 4;
id | name | age | address | tele
----+---------+-----+----------+------
1 | charlie | 40 | shanghai | 101
@ -152,13 +152,13 @@ select * from (select * from test_table order by id) as result where rownum < 4;
3 | charlie | 40 | chengdu | 101
(3 rows)
select * from (select * from test_table order by id desc) as result where rownum < 2;
select * from (select * from test_table_on_rownum order by id desc) as result where rownum < 2;
id | name | age | address | tele
----+--------+-----+---------+----------
6 | lincon | 10 | xian | 12345657
(1 row)
select * from (select * from test_table order by id asc) as result where rownum <= 5;
select * from (select * from test_table_on_rownum order by id asc) as result where rownum <= 5;
id | name | age | address | tele
----+---------+-----+----------+------
1 | charlie | 40 | shanghai | 101
@ -385,7 +385,7 @@ select rownum, * from (select * from except_table where rownum <= 3 minus select
--drop the test table
drop table rownum_table;
drop table test_table;
drop table test_table_on_rownum;
drop table distributors;
drop table actors;
drop table except_table;

View File

@ -370,6 +370,7 @@ partition p3 values less than(400)
);
CREATE INDEX t1_c2_idx ON t1 USING btree (c2) LOCAL(PARTITION p1_c2_idx, PARTITION p2_c2_idx, PARTITION p3_c2_idx);
ALTER TABLE t1 ADD CONSTRAINT t3_pkey PRIMARY KEY USING btree (c1) INCLUDE (tableoid);
\c part_expr_key_db
create table t(id int, c int default null)
partition by range(abs(id))
(PARTITION p_2017 VALUES LESS THAN (2017),

View File

@ -1234,6 +1234,7 @@ partition p3 values less than(400)
CREATE INDEX t1_c2_idx ON t1 USING btree (c2) LOCAL(PARTITION p1_c2_idx, PARTITION p2_c2_idx, PARTITION p3_c2_idx);
ALTER TABLE t1 ADD CONSTRAINT t3_pkey PRIMARY KEY USING btree (c1) INCLUDE (tableoid);
NOTICE: ALTER TABLE / ADD PRIMARY KEY will create implicit index "t3_pkey" for table "t1"
\c part_expr_key_db
create table t(id int, c int default null)
partition by range(abs(id))
(PARTITION p_2017 VALUES LESS THAN (2017),

View File

@ -1113,7 +1113,7 @@ test: test_object_alter
test: event_trigger object_address
test: event_trigger_dump_restore
# partition expression key
test: partition_expr_key instr_query_plan_threshold
test: partition_expr_key instr_query_plan_threshold null_in_partition
test: alter_foreign_schema
# test for slow_sql

View File

@ -105,7 +105,7 @@ test: hw_subpartition_createtable hw_subpartition_scan hw_subpartition_select hw
test: hw_subpartition_vacuum_partition hw_subpartition_tablespace_global
test: gs_dump_subpartition
test: partition_dml_operations partition_minmax partition_pruning hw_partitionno hw_partition_parallel
test: partition_param_path hw_subpartition_add_drop_partition_1
test: partition_param_path hw_subpartition_add_drop_partition_1 null_in_partition
#test: partition_cost_model
test: row_partition_iterator_elimination col_partition_iterator_elimination

View File

@ -82,21 +82,21 @@ select cast('s' as int);
--------------- limit #,#-------------------
-- limit case in postgresql
\c regression
create table test(a int);
insert into test values (1),(2),(3),(4),(5);
select * from test order by 1 limit 2,3;
select * from test order by 1 limit 2,6;
select * from test order by 1 limit 6,2;
drop table test;
create table test_limit_table(a int);
insert into test_limit_table values (1),(2),(3),(4),(5);
select * from test_limit_table order by 1 limit 2,3;
select * from test_limit_table order by 1 limit 2,6;
select * from test_limit_table order by 1 limit 6,2;
drop table test_limit_table;
-- limit case in B db
\c B_db
create table test(a int);
insert into test values (1),(2),(3),(4),(5);
select * from test order by 1 limit 2,3;
select * from test order by 1 limit 2,6;
select * from test order by 1 limit 6,2;
drop table test;
create table test_limit_table(a int);
insert into test_limit_table values (1),(2),(3),(4),(5);
select * from test_limit_table order by 1 limit 2,3;
select * from test_limit_table order by 1 limit 2,6;
select * from test_limit_table order by 1 limit 6,2;
drop table test_limit_table;
--------------timestampdiff-----------------
-- timestamp with time zone

View File

@ -0,0 +1,121 @@
create database null_in_partition_a dbcompatibility 'a';
\c null_in_partition_a
create table base_partition_tbl
(
num int,
data1 text
) partition by range (num) (
partition num1 values less than (10),
partition num2 values less than (20),
partition num3 values less than (30),
partition num4 values less than (MAXVALUE)
);
insert into base_partition_tbl values(null, 'test');
select * from base_partition_tbl partition (num1);
select * from base_partition_tbl partition (num4);
create table base_partition_tbl_sub_partition
(
num int,
data1 text
)
partition by range (num) SUBPARTITION BY RANGE (num) (
partition num1 values less than (10)
(
SUBPARTITION num1_1 VALUES LESS THAN( 5 ),
SUBPARTITION num1_2 VALUES LESS THAN( 10 )
),
partition num2 values less than (20) (
SUBPARTITION num2_1 VALUES LESS THAN( 15 ),
SUBPARTITION num2_2 VALUES LESS THAN( 20 )
),
partition num3 values less than (30) (
SUBPARTITION num3_1 VALUES LESS THAN( 25 ),
SUBPARTITION num4_2 VALUES LESS THAN( 30 )
),
partition num4 values less than (MAXVALUE)
(
SUBPARTITION num4_1 VALUES LESS THAN( 35 ),
SUBPARTITION num5_2 VALUES LESS THAN( MAXVALUE )
)
);
insert into base_partition_tbl_sub_partition values(null, 'test');
select * from base_partition_tbl_sub_partition subpartition (num1_1);
select * from base_partition_tbl_sub_partition subpartition (num5_2);
create table t_range (c1 int, c2 int) partition by range(c1) (partition p1 values less than (10), partition p2 values less than(maxvalue));
insert into t_range values(null),(5),(100);
create index t_range_c1_idx on t_range (c1 nulls last) local;
explain (costs off) select /*+ indexscan(t_range) */* from t_range order by c1 nulls first; -- NO INDEX
explain (costs off) select /*+ indexscan(t_range) */* from t_range order by c1 nulls last; -- INDEX
select /*+ indexscan(t_range) */* from t_range order by c1 nulls first; -- NO INDEX
select /*+ indexscan(t_range) */* from t_range order by c1 nulls last; -- INDEX
drop index t_range_c1_idx;
create index on t_range (c1 nulls first) local;
explain (costs off) select /*+ indexscan(t_range) */* from t_range order by c1 nulls first; -- INDEX
explain (costs off) select /*+ indexscan(t_range) */* from t_range order by c1 nulls last; -- NO INDEX
select /*+ indexscan(t_range) */* from t_range order by c1 nulls first; -- INDEX
select /*+ indexscan(t_range) */* from t_range order by c1 nulls last; -- NO INDEX
create database null_in_partition_b dbcompatibility 'b';
\c null_in_partition_b
create table base_partition_tbl
(
num int,
data1 text
) partition by range (num) (
partition num1 values less than (10),
partition num2 values less than (20),
partition num3 values less than (30),
partition num4 values less than (MAXVALUE)
);
insert into base_partition_tbl values(null, 'test');
select * from base_partition_tbl partition (num1);
select * from base_partition_tbl partition (num4);
create table base_partition_tbl_sub_partition
(
num int,
data1 text
)
partition by range (num) SUBPARTITION BY RANGE (num) (
partition num1 values less than (10)
(
SUBPARTITION num1_1 VALUES LESS THAN( 5 ),
SUBPARTITION num1_2 VALUES LESS THAN( 10 )
),
partition num2 values less than (20) (
SUBPARTITION num2_1 VALUES LESS THAN( 15 ),
SUBPARTITION num2_2 VALUES LESS THAN( 20 )
),
partition num3 values less than (30) (
SUBPARTITION num3_1 VALUES LESS THAN( 25 ),
SUBPARTITION num4_2 VALUES LESS THAN( 30 )
),
partition num4 values less than (MAXVALUE)
(
SUBPARTITION num4_1 VALUES LESS THAN( 35 ),
SUBPARTITION num5_2 VALUES LESS THAN( MAXVALUE )
)
);
insert into base_partition_tbl_sub_partition values(null, 'test');
select * from base_partition_tbl_sub_partition subpartition (num1_1);
select * from base_partition_tbl_sub_partition subpartition (num5_2);
create table t_range (c1 int, c2 int) partition by range(c1) (partition p1 values less than (10), partition p2 values less than(maxvalue));
insert into t_range values(null),(5),(100);
create index t_range_c1_idx on t_range (c1 nulls last) local;
explain (costs off) select /*+ indexscan(t_range) */* from t_range order by c1 nulls first; -- INDEX
explain (costs off) select /*+ indexscan(t_range) */* from t_range order by c1 nulls last; -- NO INDEX
select /*+ indexscan(t_range) */* from t_range order by c1 nulls first; -- INDEX
select /*+ indexscan(t_range) */* from t_range order by c1 nulls last; -- NO INDEX
drop index t_range_c1_idx;
create index on t_range (c1 nulls first) local;
explain (costs off) select /*+ indexscan(t_range) */* from t_range order by c1 nulls first; -- INDEX
explain (costs off) select /*+ indexscan(t_range) */* from t_range order by c1 nulls last; -- NO INDEX
select /*+ indexscan(t_range) */* from t_range order by c1 nulls first; -- INDEX
select /*+ indexscan(t_range) */* from t_range order by c1 nulls last; -- NO INDEX
\c regression
drop database null_in_partition_a;
drop database null_in_partition_b;

View File

@ -1007,7 +1007,7 @@ select * from t_multi_parts_order partition (p1) order by col limit 10;
select * from t_multi_parts_order partition (pd) order by col limit 10;
rollback;
explain delete from t_multi_parts_order partition(pd, p1) order by col limit 10;
explain (costs off) delete from t_multi_parts_order partition(pd, p1) order by col limit 10;
begin;
delete from t_multi_parts_order partition(p1, pd) order by col desc limit 10;
@ -1021,7 +1021,7 @@ select * from t_multi_parts_order partition (p1) order by col desc limit 10;
select * from t_multi_parts_order partition (pd) order by col desc limit 10;
rollback;
explain delete from t_multi_parts_order partition(pd, p1) order by col desc limit 10;
explain (costs off) delete from t_multi_parts_order partition(pd, p1) order by col desc limit 10;

View File

@ -53,7 +53,7 @@ select rownum, name, address, age from rownum_table where address = 'xian' or ro
--test order by
--create test table
create table test_table
create table test_table_on_rownum
(
id integer primary key ,
name varchar2(20) ,
@ -62,16 +62,16 @@ create table test_table
tele varchar2(20) default '101'
);
--insert data
insert into test_table values(1,'charlie', 40, 'shanghai');
insert into test_table values(2,'lincon', 10, 'xianyang');
insert into test_table values(3,'charlie', 40, 'chengdu');
insert into test_table values(4,'lincon', 10, 'xian', '');
insert into test_table values(5,'charlie', 40, 'chengdu');
insert into test_table values(6,'lincon', 10, 'xian', '12345657');
insert into test_table_on_rownum values(1,'charlie', 40, 'shanghai');
insert into test_table_on_rownum values(2,'lincon', 10, 'xianyang');
insert into test_table_on_rownum values(3,'charlie', 40, 'chengdu');
insert into test_table_on_rownum values(4,'lincon', 10, 'xian', '');
insert into test_table_on_rownum values(5,'charlie', 40, 'chengdu');
insert into test_table_on_rownum values(6,'lincon', 10, 'xian', '12345657');
--test order by
select * from (select * from test_table order by id) as result where rownum < 4;
select * from (select * from test_table order by id desc) as result where rownum < 2;
select * from (select * from test_table order by id asc) as result where rownum <= 5;
select * from (select * from test_table_on_rownum order by id) as result where rownum < 4;
select * from (select * from test_table_on_rownum order by id desc) as result where rownum < 2;
select * from (select * from test_table_on_rownum order by id asc) as result where rownum <= 5;
--test union and intersect
--create test table
@ -144,7 +144,7 @@ select rownum, * from (select * from except_table where rownum <= 3 minus select
--drop the test table
drop table rownum_table;
drop table test_table;
drop table test_table_on_rownum;
drop table distributors;
drop table actors;
drop table except_table;