《Oracle中日期字段未定义日期类型的案例一则》讲到一个用字符串类型的日期字段做分区键的案例,因为这种"不规范"的设计,通过增加一个虚拟列,才实现的日期分区的功能。
原始建表语句,这种不能按照常规的日期数据实现分区,
CREATE TABLE customer(age NUMBER, birthday char(20))PARTITION BY RANGE (birthday)(PARTITION p1 VALUES less than (to_date('2022-01','yyyy-mm')),PARTITION p2 VALUES less than (to_date('2022-02','yyyy-mm')),PARTITION p3 VALUES less than (to_date('2022-03','yyyy-mm')));
改造成增加一个虚拟列的建表语句,
CREATE TABLE customer(age NUMBER, birthday char(20), partiton_key DATE GENERATED ALWAYS AS (to_date(birthday, 'yyyy-mm-dd')))PARTITION BY RANGE (partiton_key)(PARTITION p1 VALUES less than (to_date('2022-01','yyyy-mm')),PARTITION p2 VALUES less than (to_date('2022-02','yyyy-mm')),PARTITION p3 VALUES less than (to_date('2022-03','yyyy-mm')));
此时虽然能实现正常的日期分区的功能,但是每次插入INSERT,必须带着除虚拟列外其他的字段,给开发增加了复杂度,
SQL> insert into customer values(1, '2022-01-01');insert into customer3 values(1, '2022-01-01')*ERROR at line 1:ORA-00947: not enough valuesINSERT INTO customer(age, birthday) values(1, '2022-01-01');
实际上,有时候我们日常的生活中,碰到一个问题,往往可能高估他的难度,或者在潜意识当中认为需要用特殊的方案才可以解决,但实际上,可能最简单的方案就在眼前,这个案例,就是如此。
分区条件直接用字符串,不用to_date(),无论是采用"月",还是"日",
CREATE TABLE customer1(age NUMBER, birthday char(20))PARTITION BY RANGE (birthday)(PARTITION p1 VALUES less than ('2022-01'),PARTITION p2 VALUES less than ('2022-02'),PARTITION p3 VALUES less than ('2022-03'));CREATE TABLE customer2(age NUMBER, birthday char(20))PARTITION BY RANGE (birthday)(PARTITION p1 VALUES less than ('2022-01-01'),PARTITION p2 VALUES less than ('2022-02-01'),PARTITION p3 VALUES less than ('2022-03-01'));
如下插入语句,都是能执行的,
INSERT INTO customer1 values(1, '2022-01-01');INSERT INTO customer1 values(1, '2022-02-01');INSERT INTO customer1 values(2, '2022-02-02');INSERT INTO customer2 values(1, '2022-01-01');INSERT INTO customer2 values(1, '2022-02-01');INSERT INTO customer2 values(2, '2022-02-02');
而且分区数据,都是正确的,这是按照"月"的,
SQL> SELECT * FROM customer1;AGE BIRTHDAY---------- --------------------1 2022-01-011 2022-02-012 2022-02-02SQL> SELECT * FROM customer1 PARTITION(p2);AGE BIRTHDAY---------- --------------------1 2022-01-01SQL> SELECT * FROM customer1 PARTITION(p3);AGE BIRTHDAY---------- --------------------1 2022-02-012 2022-02-02
这是按照"天"的,
SQL> SELECT * FROM customer2;AGE BIRTHDAY---------- --------------------1 2022-01-011 2022-02-012 2022-02-02SQL> SELECT * FROM customer2 PARTITION(p2);AGE BIRTHDAY---------- --------------------1 2022-01-01SQL> SELECT * FROM customer2 PARTITION(p3);AGE BIRTHDAY---------- --------------------1 2022-02-012 2022-02-02
所以有时候,问题可以先从自身或者最简单的形式考虑,或许就可以得到答案,当然,这还取决于对原理的理解,如果理解到位,可能就脱口而出,否则就会像上面这种,绕道而行,缺练。
近期更新的文章:
文章分类和索引:
文章转载自bisal的个人杂货铺,如果涉嫌侵权,请发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




