104 lines
1.9 KiB
Markdown
104 lines
1.9 KiB
Markdown
# edb 12 创建分区表
|
|
|
|
edb12 兼容oracle 11g
|
|
|
|
可以使用Oracle 的自动分区。
|
|
|
|
```sql
|
|
CREATE TABLE ckw_test (
|
|
id bigserial NOT NULL,
|
|
"name" varchar(255) NULL,
|
|
afferent_date timestamp NOT null
|
|
)PARTITION BY RANGE (afferent_date)
|
|
INTERVAL (NUMTOYMINTERVAL(1,'MONTH'))
|
|
(
|
|
partition part_202209 values less than('20221001')
|
|
) ;
|
|
```
|
|
|
|
|
|
|
|
普通分区转自动分区
|
|
|
|
```sql
|
|
ALTER TABLE <table_name> SET INTERVAL (<constant> | <expression>);
|
|
|
|
ALTER TABLE ckw_test SET INTERVAL (NUMTOYMINTERVAL(1,'MONTH'))
|
|
|
|
```
|
|
|
|
自动分区单位
|
|
|
|
```sql
|
|
--年-月
|
|
NUMTOYMINTERVAL(1,'year')
|
|
NUMTOYMINTERVAL(1,'month')
|
|
|
|
|
|
--日-时-分-秒
|
|
numtodsinterval(1,'day')
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
查询分区表信息
|
|
|
|
```sql
|
|
select * from dba_tab_partitions where table_name='TCN_STAT';
|
|
SELECT * FROM ALL_TAB_PARTITIONS;
|
|
```
|
|
|
|
|
|
|
|
分区表操作
|
|
|
|
```sql
|
|
-- 分离分区表
|
|
ALTER TABLE tcn_stat DETACH PARTITION tcn_stat_part_default;
|
|
|
|
-- 附加分区表(数据不能与分区规则冲突)
|
|
|
|
--附加分区 需要指定 分区条件
|
|
ALTER TABLE tcn_stat ATTACH PARTITION tcn_stat_part_default;
|
|
|
|
-- 默认分区
|
|
ALTER TABLE ckw_test ATTACH PARTITION ckw_test_part_default DEFAULT;
|
|
-- 小于2022-10-01 的数据
|
|
ALTER TABLE ckw_test ATTACH PARTITION ckw_test_part_default values less than('20221001')
|
|
-- 区间数据
|
|
ALTER TABLE ckw_test ATTACH PARTITION ckw_test_part_default VALUES from ('20190101') TO ('20190201');
|
|
|
|
|
|
|
|
-- 合并操作
|
|
select table_name,high_value,partition_name from dba_tab_partitions where table_name='t1';
|
|
|
|
alter table t1 merge partitions p2,p1 into partition p1_2;
|
|
|
|
|
|
|
|
-- 拆分分区
|
|
-- at() 括号里为分割条件 如 '20190101'
|
|
alter table t1 split partition p1_2 at(100) into (partition p1,partition p2);
|
|
|
|
|
|
|
|
-- 删除分区
|
|
alter table t1 drop partition p3;
|
|
|
|
|
|
|
|
|
|
-- 交换分区
|
|
-- 用表test_t1 替换 t1的分区p2
|
|
create table test_t1 (id int,name varchar2(20));
|
|
alter table t1 exchange partition p2 with table test_t1;
|
|
|
|
|
|
|
|
```
|
|
|