Chinaunix首页 | 论坛 | 博客
  • 博客访问: 4043148
  • 博文数量: 536
  • 博客积分: 10470
  • 博客等级: 上将
  • 技术积分: 4825
  • 用 户 组: 普通用户
  • 注册时间: 2006-05-26 14:08
文章分类

全部博文(536)

文章存档

2024年(3)

2021年(1)

2019年(1)

2017年(1)

2016年(2)

2013年(2)

2012年(10)

2011年(43)

2010年(10)

2009年(17)

2008年(121)

2007年(252)

2006年(73)

分类: Oracle

2006-12-08 15:05:33

INTERVAL YEAR TO MONTH数据类型

Oracle语法:
INTERVAL 'integer [- integer]' {YEAR | MONTH} [(precision)][TO {YEAR | MONTH}]

该数据类型常用来表示一段时间差, 注意时间差只精确到年和月. precision为年或月的精确域, 有效范围是0到9, 默认值为2.

eg:
INTERVAL '123-2' YEAR(3) TO MONTH     
表示: 123年2个月, "YEAR(3)" 表示年的精度为3, 可见"123"刚好为3为有效数值, 如果该处YEAR(n), n<3就会出错, 注意默认是2.

INTERVAL '123' YEAR(3)
表示: 123年0个月

INTERVAL '300' MONTH(3)
表示: 300个月, 注意该处MONTH的精度是3啊.

INTERVAL '4' YEAR     
表示: 4年, 同 INTERVAL '4-0' YEAR TO MONTH 是一样的

INTERVAL '50' MONTH     
表示: 50个月, 同 INTERVAL '4-2' YEAR TO MONTH 是一样

INTERVAL '123' YEAR     
表示: 该处表示有错误, 123精度是3了, 但系统默认是2, 所以该处应该写成 INTERVAL '123' YEAR(3) 或"3"改成大于3小于等于9的数值都可以的

INTERVAL '5-3' YEAR TO MONTH + INTERVAL '20' MONTH =
INTERVAL '6-11' YEAR TO MONTH
表示: 5年3个月 + 20个月 = 6年11个月

与该类型相关的函数:
NUMTODSINTERVAL(n, 'interval_unit')
将n转换成interval_unit所指定的值, interval_unit可以为: DAY, HOUR, MINUTE, SECOND
注意该函数不可以转换成YEAR和MONTH的.

NUMTOYMINTERVAL(n, 'interval_unit')
interval_unit可以为: YEAR, MONTH

eg: (Oracle Version 9204, RedHat Linux 9.0)
SQL> select numtodsinterval(100,'DAY') from dual;

NUMTODSINTERVAL(100,'DAY')                                                      
---------------------------------------------------------------------------     
+000000100 00:00:00.000000000                                                   

SQL> c/DAY/SECOND
  1* select numtodsinterval(100,'SECOND') from dual
SQL> /

NUMTODSINTERVAL(100,'SECOND')                                                   
---------------------------------------------------------------------------     
+000000000 00:01:40.000000000                                                   

SQL> c/SECOND/MINUTE
  1* select numtodsinterval(100,'MINUTE') from dual
SQL> /

NUMTODSINTERVAL(100,'MINUTE')                                                   
---------------------------------------------------------------------------     
+000000000 01:40:00.000000000                                                   

SQL> c/MINUTE/HOUR
  1* select numtodsinterval(100,'HOUR') from dual
SQL> /

NUMTODSINTERVAL(100,'HOUR')                                                     
---------------------------------------------------------------------------     
+000000004 04:00:00.000000000                                                   

SQL> c/HOUR/YEAR
  1* select numtodsinterval(100,'YEAR') from dual
SQL> /
select numtodsinterval(100,'YEAR') from dual
                           *
ERROR at line 1:
ORA-01760: illegal argument for function

SQL> select numtoyminterval(100,'year') from dual;

NUMTOYMINTERVAL(100,'YEAR')                                                     
---------------------------------------------------------------------------     
+000000100-00                                                                   

SQL> c/year/month
  1* select numtoyminterval(100,'month') from dual
SQL> /

NUMTOYMINTERVAL(100,'MONTH')                                                    
---------------------------------------------------------------------------     
+000000008-04                                                                   


时间的计算:
SQL> select to_date('1999-12-12','yyyy-mm-dd') - to_date('1999-12-01','yyyy-mm-dd') from dual;

TO_DATE('1999-12-12','YYYY-MM-DD')-TO_DATE('1999-12-01','YYYY-MM-DD')           
---------------------------------------------------------------------           
                                                                   11           
-- 可以相减的结果为天.

SQL> c/1999-12-12/1999-01-12
  1* select to_date('1999-01-12','yyyy-mm-dd') - to_date('1999-12-01','yyyy-mm-dd') from dual
SQL> /

TO_DATE('1999-01-12','YYYY-MM-DD')-TO_DATE('1999-12-01','YYYY-MM-DD')           
---------------------------------------------------------------------           
                                                                 -323           
-- 也可以为负数的

SQL> c/1999-01-12/2999-10-12
  1* select to_date('2999-10-12','yyyy-mm-dd') - to_date('1999-12-01','yyyy-mm-dd') from dual
SQL> /

TO_DATE('2999-10-12','YYYY-MM-DD')-TO_DATE('1999-12-01','YYYY-MM-DD')           
---------------------------------------------------------------------           
                                                               365193           

下面看看INTERVAL YEAR TO MONTH怎么用.
SQL> create table bb(a date, b date, c interval year(9) to month);

Table created.

SQL> desc bb;
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 A                                                  DATE
 B                                                  DATE
 C                                                  INTERVAL YEAR(9) TO MONTH

SQL> insert into bb values(to_date('1985-12-12', 'yyyy-mm-dd'), to_date('1984-12-01','yyyy-mm-dd'), null)

1 row created.

SQL> select * from bb;

A         B                                                                     
--------- ---------                                                             
C                                                                               
---------------------------------------------------------------------------     
12-DEC-85 01-DEC-84                                                             
                                                                                
                                                                               
SQL> update bb set c = numtoyminterval(a-b, 'year');

1 row updated.

SQL> select * from bb;

A         B                                                                    
--------- ---------                                                            
C                                                                              
---------------------------------------------------------------------------    
12-DEC-85 01-DEC-84                                                            
+000000376-00                                                                  
                                                                               
-- 直接将相减的天变成年了, 因为我指定变成年的
SQL> select a-b, c from bb;

       A-B                                                                     
----------                                                                     
C                                                                              
---------------------------------------------------------------------------    
       376                                                                     
+000000376-00                                                                  
                                                                               

SQL> insert into bb values(null,null,numtoyminterval(376,'month'));

1 row created.

SQL> select * from bb;

A         B             C                                                       
--------- ---------    --------------------------------------------    
12-DEC-85 01-DEC-84    +000000376-00                                                                  
                         +000000031-04                                         

SQL> insert into bb values ( null,null, numtoyminterval(999999999,'year'));

1 row created.

SQL> select * from bb;

A           B            C                                
---------   ---------     ---------------------------------------------------------------------    
12-DEC-85   01-DEC-84   +000000376-00                                                                  
                          +000000031-04
                          +999999999-00                                                                
 
========================
今天来添加点新的东西![2008-07-26] 这部分东东来源:http://www.oraclefans.cn/forum/showblog.jsp?rootid=139

INTERVAL YEAR TO MONTH类型2个TIMESTAMP类型的时间差别。内部类型是182,长度是5。其中4个字节存储年份差异,存储的时候在差异上加了一个0X80000000的偏移量。一个字节存储月份的差异,这个差异加了60的偏移量。

SQL> ALTER TABLE TestTimeStamp ADD E INTERVAL YEAR TO MONTH;
SQL> update testTimeStamp set e=(select interval '5' year + interval '10' month year  from dual);

已更新3行。

SQL> commit;

提交完成。

SQL> select dump(e,16) from testTimeStamp;

DUMP(E,16)

---------------------------------------------

Typ=182 Len=5: 80,0,0,5,46

Typ=182 Len=5: 80,0,0,5,46

Typ=182 Len=5: 80,0,0,5,46

年:0X80000005-0X80000000=5

月:0x46-60=10
 
阅读(5300) | 评论(2) | 转发(0) |
给主人留下些什么吧!~~

chinaunix网友2009-06-07 08:57:48

不错