Categories
Cast a date field in UTC to LOCAL time zone with OBIEE

Hi,
We are using FTI (fusion transport intelligent in OTM) with OBIEE and we need to transform the date field in UTC to local timezone.
How to perform the formulas to transform the data on the criteria formula?
Thanks and regards.
Pablo.
Best Answer
-
here is an example showing a fully worked demo in SQL
You'll see the code used to convert UTC to local in the SELECT
SQL> CREATE TABLE imported_events (event_date TIMESTAMP(0) WITH TIME ZONE); Table created. SQL> BEGIN 2 INSERT INTO imported_events VALUES ( '10-JAN-08 2:00:00 PM UTC'); 3 INSERT INTO imported_events VALUES ( '08-MAR-08 2:00:00 PM UTC'); 4 INSERT INTO imported_events VALUES ( '09-MAR-08 6:59:00 AM UTC'); 5 INSERT INTO imported_events VALUES ( '09-MAR-08 7:01:00 AM UTC'); 6 INSERT INTO imported_events VALUES ( '09-MAR-08 2:00:00 PM UTC'); 7 INSERT INTO imported_events VALUES ( '10-MAR-08 2:00:00 PM UTC'); 8 INSERT INTO imported_events VALUES ( '09-JUN-08 2:00:00 PM UTC'); 9 COMMIT; 10 END; 11 / SQL> COLUMN ROWNUM FORMAT 99 SQL> COLUMN event_date_utc FORMAT A25 SQL> COLUMN offset_local FORMAT 99 SQL> COLUMN offset_eastern FORMAT 99 SQL> SELECT ROWNUM 2 ,event_date event_date_utc 3 ,TO_CHAR(CAST((event_date AT LOCAL) AS DATE),'YYYY-MM-DD HH24:MI:SS') date_local 4 ,(CAST((event_date AT LOCAL) AS DATE) - CAST(event_date AS DATE))*24 offset_local 5 ,TO_CHAR(CAST((event_date AT TIME ZONE 'US/Eastern') AS DATE),'YYYY-MM-DD HH24:MI:SS') date_eastern 6 ,(CAST((event_date AT TIME ZONE 'US/Eastern') AS DATE) - CAST(event_date AS DATE))*24 offset_eastern 7 FROM imported_events 8 ORDER BY 1; ROWNUM EVENT_DATE_UTC DATE_LOCAL OFFSET_LOCAL DATE_EASTERN OFFSET_EASTERN ------ ------------------------- ------------------- ------------ ------------------- -------------- 1 10-JAN-08 02.00.00 PM UTC 2008-01-10 10:00:00 -4 2008-01-10 09:00:00 -5 2 08-MAR-08 02.00.00 PM UTC 2008-03-08 10:00:00 -4 2008-03-08 09:00:00 -5 3 09-MAR-08 06.59.00 AM UTC 2008-03-09 02:59:00 -4 2008-03-09 01:59:00 -5 4 09-MAR-08 07.01.00 AM UTC 2008-03-09 03:01:00 -4 2008-03-09 02:01:00 -5 5 09-MAR-08 02.00.00 PM UTC 2008-03-09 10:00:00 -4 2008-03-09 09:00:00 -5 6 10-MAR-08 02.00.00 PM UTC 2008-03-10 10:00:00 -4 2008-03-10 09:00:00 -5 7 09-JUN-08 02.00.00 PM UTC 2008-06-09 10:00:00 -4 2008-06-09 10:00:00 -4 7 rows selected.
Another option is
CAST((FROM_TZ(CAST(utc_date AS TIMESTAMP),'UTC') AT TIME ZONE 'CST') AS DATE) cst_date
select from_tz(CAST ('15-oct-2014' AS TIMESTAMP),'GMT') at TIME ZONE 'US/Central' with_daylight_savings, from_tz(CAST ('15-nov-2014' AS TIMESTAMP),'GMT') at TIME ZONE 'US/Central' without_daylight_savings from dual;
1
Answers
-
Hi Pablo,
Welcome to the Oracle Analytics community and thanks for your question.
To add to Brendan's excellent response, you can also use use variables.DATA_TZ
andDATA_DISPLAY_TZ
0 -
Hi guys,
The problem is that the OBIEE formula box doesn't accept Oracle DB functions. For example, the following functions transform the date into a specific format:
But then when I try to put them in a similar way in the formula of the tool it does not accept the syntax and gives an error:
I think the FROM_TZ function is not supported in OBIIE.
Is there any similar function for OBIEE?
Thanks and regards.
0 -
OBIEE usually automatically convert date/time to the user account time zone configuration. It does it on all the dates columns not having a time zone (they are considered UTC and therefore adapted to the user).
In your case, what is the physical data type of that column? Because that could be the reason why OBIEE isn't doing the translation automatically.
If you want a fixed conversion adding/subtracting a fixed number of hours, you can use TIMESTAMPADD(…)
0 -
To use database functions, you have to enable and use EVALUATE
FROM_TZ function is a database function, not an OBI function1 -
Here's a link to a previous post/discussion about using EVALUATE. It also contains a link to a website with some examples
0 -
Hi,
I think we have not permissions for use EVALUATE function in OTM FTI version. There is a limited version if OBIEE. I get several errors.
TIMESTAMPADD(…) is an option I was considering, the problem is that it is not always the same time difference, depending on the day of the year it can be +1 (from October to March) or +2 (from March to October)
Thanks and regards
0