일단 아래 a.sql 을 음미해보세요.
$> cat a.sql
select now(), current_timestamp, timeofday();
select pg_sleep(1);
select now(), current_timestamp, timeofday();
begin;
select now(), current_timestamp, timeofday();
select pg_sleep(1);
select now(), current_timestamp, timeofday();
select pg_sleep(1);
select now(), current_timestamp, timeofday();
rollback;
select now(), current_timestamp, timeofday();
select pg_sleep(1);
select now(), current_timestamp, timeofday();
$>
-- now() 와 current_timestamp 는 동의어입니다.
-- pg_sleep(1) 은 1초 만큼 쉬겠다는 의미입니다.
$> psql -f a.sql -- 이제 실행시켜 볼까요?
now | now | timeofday
-------------------------------+-------------------------------+-------------------------------------
2014-11-11 02:13:07.662907+09 | 2014-11-11 02:13:07.662907+09 | Tue Nov 11 02:13:07.663760 2014 KST
(1 row)
pg_sleep
----------
(1 row)
now | now | timeofday
-------------------------------+-------------------------------+-------------------------------------
2014-11-11 02:13:08.667238+09 | 2014-11-11 02:13:08.667238+09 | Tue Nov 11 02:13:08.667349 2014 KST
(1 row)
BEGIN
now | now | timeofday
-------------------------------+-------------------------------+-------------------------------------
2014-11-11 02:13:08.667904+09 | 2014-11-11 02:13:08.667904+09 | Tue Nov 11 02:13:08.668357 2014 KST
(1 row)
pg_sleep
----------
(1 row)
now | now | timeofday
-------------------------------+-------------------------------+-------------------------------------
2014-11-11 02:13:08.667904+09 | 2014-11-11 02:13:08.667904+09 | Tue Nov 11 02:13:09.671390 2014 KST
(1 row)
pg_sleep
----------
(1 row)
now | now | timeofday
-------------------------------+-------------------------------+-------------------------------------
2014-11-11 02:13:08.667904+09 | 2014-11-11 02:13:08.667904+09 | Tue Nov 11 02:13:10.674596 2014 KST
(1 row)
ROLLBACK
now | now | timeofday
-------------------------------+-------------------------------+-------------------------------------
2014-11-11 02:13:10.676134+09 | 2014-11-11 02:13:10.676134+09 | Tue Nov 11 02:13:10.676236 2014 KST
(1 row)
pg_sleep
----------
(1 row)
now | now | timeofday
-------------------------------+-------------------------------+-------------------------------------
2014-11-11 02:13:11.679289+09 | 2014-11-11 02:13:11.679289+09 | Tue Nov 11 02:13:11.679478 2014 KST
(1 row)
$>
위 결과를 자세히 살펴보면 begin..rollback; 트랜젹션 구간의 now() 와 current_timestamp 값은
이상하게도 값이 변하지 않고 있습니다. timeofday() 만 변하고 있네요.
now()/current_timestamp 는 단순히 현재의 시각을 반환하는 함수가 아닌거 같네요.
일반적인 오라클의 sysdate 와 다른 개념 인가봅니다.
그럼 무슨 시간을 의미하는걸까요?
퀴즈입니다!