From ae6f93029043f670eb24403fca8fd9d81127caba Mon Sep 17 00:00:00 2001 From: Dan McGhan Date: Thu, 3 Nov 2016 10:20:28 -0400 Subject: [PATCH 1/2] Update oos_util_date.pks Alternative implementation. Removed timestamp2epoch in favor of implicit data conversion. Here, date2epoch uses the timestamp data type so if a date is passed it doesn't lose precision but any timestamp data type can be passed without losing milliseconds. Also, both functions now have an additional tzr parameter which allows for additional flexibility when needed. In the case of date2epoch, the parameter can be used to specify which timezone the date or timestamp being passed in is from. For epoch2date, the tzr parameter allows the user to get a date back in a specific timezone. The tzr parameter defaults to the sessiontimezone for convenience. --- source/packages/oos_util_date.pks | 13 +++++-------- 1 file changed, 5 insertions(+), 8 deletions(-) diff --git a/source/packages/oos_util_date.pks b/source/packages/oos_util_date.pks index 31071fc..cf11348 100644 --- a/source/packages/oos_util_date.pks +++ b/source/packages/oos_util_date.pks @@ -1,17 +1,14 @@ create or replace package oos_util_date as - function date2epoch( - p_date in date) + p_date timestamp, + p_date_in_tzr in varchar2 default sessiontimezone) return number; function epoch2date( - p_epoch in number) - return date; - - function timestamp2epoch( - p_timestamp in timestamp) - return pls_integer; + p_epoch in number, + p_date_out_tzr in varchar2 default sessiontimezone) + return timestamp with time zone; end oos_util_date; / From aa58e408535b97c80288ed7037354e96addd9fd6 Mon Sep 17 00:00:00 2001 From: Dan McGhan Date: Thu, 3 Nov 2016 10:21:07 -0400 Subject: [PATCH 2/2] Update oos_util_date.pkb Updated implementation of epoch functions. --- source/packages/oos_util_date.pkb | 61 +++++++++---------------------- 1 file changed, 17 insertions(+), 44 deletions(-) diff --git a/source/packages/oos_util_date.pkb b/source/packages/oos_util_date.pkb index 37ff8fb..58ec4c7 100644 --- a/source/packages/oos_util_date.pkb +++ b/source/packages/oos_util_date.pkb @@ -25,17 +25,23 @@ as * @return Unix Epoch time */ function date2epoch( - p_date in date) + p_date timestamp, + p_date_in_tzr in varchar2 default sessiontimezone) return number as $if dbms_db_version.version >= 12 $then pragma udf; $end + + l_tswtz timestamp with time zone; + l_start timestamp with time zone := to_timestamp_tz('19700101 utc', 'yyyymmdd tzr'); begin - return - round( - (p_date - to_date ('19700101', 'yyyymmdd')) * 86400 - - (to_number(substr (tz_offset (sessiontimezone), 1, 3))+0) * 3600); -- Note: Was +1 but was causing 1 hour behind (#123) + l_tswtz := from_tz(p_date, p_date_in_tzr) at time zone 'utc'; + + return round((extract (day from l_tswtz - l_start) * 86400000) + + (extract (hour from l_tswtz - l_start) * 3600000) + + (extract (minute from l_tswtz - l_start) * 60000) + + (extract (second from l_tswtz - l_start) * 1000)); end date2epoch; @@ -59,48 +65,15 @@ as * @return date */ function epoch2date( - p_epoch in number) - return date + p_epoch in number, + p_date_out_tzr in varchar2 default sessiontimezone) + return timestamp with time zone as - + l_tswtz timestamp with time zone; begin - return - to_date ('19700101', 'yyyymmdd') - + ((p_epoch + ((to_number(substr(tz_offset(sessiontimezone), 1, 3))+0) * 3600)) / 86400); -- Note: Was +1 but was causing 1 hour ahead (#123) + l_tswtz := to_timestamp_tz('19700101 utc', 'yyyymmdd tzr') + numtodsinterval(p_epoch/86400000, 'day'); + return l_tswtz at time zone (p_date_out_tzr); end epoch2date; - - - /*! - * Coverts timestamp to Unix Epoch time - * - * @private Currently used for crypto. Needs more testing to make puplically available. - * - * @example - * - * select oos_util_date.timestamp2epoch(current_timestamp) - * from dual; - * - * OOS_UTIL_DATE.TIMESTAMP2EPOCH(CURRENT_TIMESTAMP) - * --------------------------------- - * 1474277938 - * - * @author Adrian Png - * @created 22-Sep-2016 - * @param p_timestamp Timestamp to convert to Epoch format - * @return Unix Epoch time - */ - function timestamp2epoch( - p_timestamp in timestamp) - return pls_integer - as - c_start_time constant timestamp with time zone := timestamp '1970-01-01 00:00:00 +00:00'; - begin - return extract(day from (p_timestamp - c_start_time)) * 86400 - + extract(hour from (p_timestamp - c_start_time)) * 3600 - + extract(minute from (p_timestamp - c_start_time)) * 60 - + extract(second from (p_timestamp - c_start_time)) - ; - end timestamp2epoch; end oos_util_date;