Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
![]() |
![]() |
Home -> Community -> Mailing Lists -> Oracle-L -> Re: update year in date column
I'm not sure why you would be subtracting 1000 from the bad date, even if
you were actually subtracting years and not days. If I'm understanding you,
you really want to subtract 100 years from the bad dates. Try this: update
custtable set crdate = add_months(crdate, -(12*100));
Script started on Tue Mar 23 17:25:31 2004 $ sqlplus /
SQL*Plus: Release 8.1.7.0.0 - Production on Tue Mar 23 17:25:33 2004
(c) Copyright 2000 Oracle Corporation. All rights reserved.
Connected to:
Oracle8i Release 8.1.7.2.0 - Production
JServer Release 8.1.7.2.0 - Production
SQL> set lines 132 pages 50000
SQL> alter session set nls_date_format = 'MM/DD/YYYY HH24:MI:SS';
Session altered.
SQL> create table baddate (
2 cusno number(38,0) primary key, 3 cusname varchar2(15), 4 crdate date );
Table created.
SQL> insert into baddate values (
2 798489, 'GILBERT, ROSS', 3 to_date('09/16/2099 13:13', 'mm/dd/yyyy hh24:mi'));
1 row created.
SQL> insert into baddate values (
2 826744, 'HOEFLER, MATT', 3 to_date('10/08/2099 10:10', 'mm/dd/yyyy hh24:mi'));
1 row created.
SQL> insert into baddate values (
2 795126, 'FORT, JOETTA', 3 to_date('09/08/2099 15:15', 'mm/dd/yyyy hh24:mi'));
1 row created.
SQL> select * from baddate;
CUSNO CUSNAME CRDATE
---------- --------------- ------------------- 798489 GILBERT, ROSS 09/16/2099 13:13:00826744 HOEFLER, MATT 10/08/2099 10:10:00 795126 FORT, JOETTA 09/08/2099 15:15:00 SQL> update baddate set crdate = add_months(crdate, -(12*100));
3 rows updated.
SQL> select * from baddate;
CUSNO CUSNAME CRDATE
---------- --------------- ------------------- 798489 GILBERT, ROSS 09/16/1999 13:13:00826744 HOEFLER, MATT 10/08/1999 10:10:00 795126 FORT, JOETTA 09/08/1999 15:15:00 SQL> drop table baddate;
Table dropped.
SQL> exit
Disconnected from Oracle8i Release 8.1.7.2.0 - Production
JServer Release 8.1.7.2.0 - Production
$
script done on Tue Mar 23 17:27:09 2004
OK, I'm just going to bite the bullet and claim total
ignorance here and see if someone takes pity on me :(
(sad face a nice touch, eh?)
Someone has accidently updated 378 records in the customer table. The date changed from 1999 to 2099. I need to change just the year back to 1999 for these records. (I'd like to keep the time stamp, if possible. The month and day are correct.) I looked on metalink, google, and asktom. Some nice examples, but not what I really need.
Thought I'd be clever and subtract 1000 from the date. This works, but I don't know how to get it formatted back into a date.
I'd prefer just sqlplus, but will use pl/sql if necessary.
Here's what I've done so far:
(solaris 9 oracle 9.2.0.4)
JServer Release 9.2.0.4.0 - Production
DOC> CUSNO CUSNAME
CRDATE
DOC>---------- -----------------------------------
SQL> ---update advdb.custtest_barb SQL> ---set crdate= to_char(crdate,'MM/DD/YYYY')) SQL> ---from customer where cusno=798489; SQL> SQL> select to_date(to_char(crdate,'ddmmyyyy')-1000),'MM/DD/YYYY') 2 from customer where cusno=798489;select
*
ERROR at line 1:
ORA-00923: FROM keyword not found where expected
SQL> SQL> SQL> --- these both work SQL> select to_char(crdate,'ddmmyyyy') fromcusttest_barb where cusno=798489;
TO_CHAR(
SQL> select to_char(crdate,'ddmmyyyy') - 1000 from custtest_barb where cusno=798489;
TO_CHAR(CRDATE,'DDMMYYYY')-1000
16091099
Thank for any assistance.
Barb
-- Archives are at http://www.freelists.org/archives/oracle-l/ FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html ----------------------------------------------------------------- ---------------------------------------------------------------- Please see the official ORACLE-L FAQ: http://www.orafaq.com ---------------------------------------------------------------- To unsubscribe send email to: oracle-l-request_at_freelists.org put 'unsubscribe' in the subject line. -- Archives are at http://www.freelists.org/archives/oracle-l/ FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html -----------------------------------------------------------------Received on Tue Mar 23 2004 - 18:36:23 CST
![]() |
![]() |