今天有一开发兄弟找我。说出现一奇怪现象,在存储过程中赋date类型的值,时、分、秒都丢失了,以下来做个试验:

SQL> drop table test purge;

SQL> create table test

    (

     fill_date  date

    );

SQL> insert into test values(sysdate);

SQL> commit;

SQL> select to_char(fill_date,'yyyy-MM-dd HH24:mi:ss') from test;

TO_CHAR(FILL_DATE,'

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

2014-07-18 17:47:22

SQL> CREATE OR REPLACE PROCEDURE test_p

is

s_sql varchar2(500);

s_date date;

begin

s_date:= to_date('2014-07-18 17:24:32','yyyy-MM-dd HH24:mi:ss');

s_sql := 'UPDATE test SET fill_date = '''||s_date ||'''';

execute immediate s_sql;

commit;

end;

/

SQL> call test_p();

SQL> select to_char(fill_date,'yyyy-MM-dd HH24:mi:ss') from test;

TO_CHAR(FILL_DATE,'

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

2014-07-18 00:00:00     --能够看到确实时、分、秒已经丢失,怀疑是隐式转换导致

--调整下存储过程。看打印出什么来。

SQL> CREATE OR REPLACE PROCEDURE test_p

is

s_sql varchar2(500);

s_date date;

begin

s_date:= to_date('2014-07-18 17:24:32','yyyy-MM-dd HH24:mi:ss');

s_sql := 'UPDATE test SET fill_date = '''||s_date ||'''';

dbms_output.put_line(s_sql);

execute immediate s_sql;

commit;

end;

/

SQL> set serveroutput on

SQL> call test_p();

UPDATE test SET fill_date = '18-7月 -14'

调用完毕。

--确认发生了隐式转换,那就使用绑定变量了

SQL> CREATE OR REPLACE PROCEDURE test_p

is

s_sql varchar2(500);

s_date date;

begin

s_date:= to_date('2014-07-18 17:24:32','yyyy-MM-dd HH24:mi:ss');

s_sql := 'UPDATE test SET fill_date = :1';

execute immediate s_sql using s_date;

commit;

end;

/

SQL> call test_p();

调用完毕。

SQL> select to_char(fill_date,'yyyy-MM-dd HH24:mi:ss') from test;

TO_CHAR(FILL_DATE,'

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

2014-07-18 17:24:32

05-23 04:29