|
| 1 | +# Time zone |
| 2 | + |
| 3 | +## Time zone parameters |
| 4 | + |
| 5 | +Teradata define time zone at three level: |
| 6 | + |
| 7 | +- Server |
| 8 | + |
| 9 | +- User |
| 10 | + |
| 11 | +- Session |
| 12 | + |
| 13 | +### Server Time zone |
| 14 | + |
| 15 | +It is set in /etc/opt/teradata/tdconfig/tdlocaledef.txt |
| 16 | + |
| 17 | +It looks like: |
| 18 | + |
| 19 | +``` |
| 20 | +Time ZoneString { |
| 21 | + "Europe Central"; "1"; "0"; "2"; |
| 22 | + "3"; "3"; "0"; "0"; "-1"; "02:00:00"; |
| 23 | + "3"; "9"; "0"; "0"; "-1"; "03:00:00"; |
| 24 | + "1987"; "1995"; "1"; "0"; "2"; "0"; |
| 25 | + "3"; "3"; "0"; "0"; "-1"; "02:00:00"; |
| 26 | + "3"; "10"; "0"; "0"; "-1"; "03:00:00"; |
| 27 | + "1996"; "9999"; "1"; "0"; "2"; "0" |
| 28 | +} |
| 29 | +``` |
| 30 | + |
| 31 | +The value can be seen in dbscontrol (but not modified). |
| 32 | + |
| 33 | +### User Time zone |
| 34 | + |
| 35 | +A Time zone can be define for each user. |
| 36 | + |
| 37 | +If the time zone is not defined, the user will use **server time zone**. |
| 38 | + |
| 39 | +> **Warning: as stated in Teradata documentation, NO specific time should be defined on users.** |
| 40 | +
|
| 41 | +#### Define User time Zone |
| 42 | + |
| 43 | +During user creation, you can define a specific time zone using the parameter `Time Zone`. |
| 44 | + |
| 45 | +```sql |
| 46 | +create user user_name |
| 47 | + from database_name |
| 48 | + as ... |
| 49 | + time zone = 'Europe Central' |
| 50 | +``` |
| 51 | + |
| 52 | +#### Change Time zone |
| 53 | + |
| 54 | +```sql |
| 55 | +modify user user_name as time zone = 'Europe Central'; |
| 56 | +-- or |
| 57 | +modify user user_name as time zone = '+01:00'; |
| 58 | +-- Remove user specific time zone |
| 59 | +modify user user_name as time zone = null; |
| 60 | +``` |
| 61 | + |
| 62 | +#### Show user time zone |
| 63 | + |
| 64 | +```sql |
| 65 | +select |
| 66 | + username, |
| 67 | + TimeZoneHour, |
| 68 | + TimeZoneMinute, |
| 69 | + TimeZoneString |
| 70 | +from "DBC".UsersV |
| 71 | +``` |
| 72 | +The time zone is defined either in TimeZoneHour + TimeZoneMinute or in TimeZoneString |
| 73 | + |
| 74 | +### Session time zone |
| 75 | + |
| 76 | +```sql |
| 77 | +set time zone 'Europe Central'; |
| 78 | +-- or |
| 79 | +set time zone '+01:00'; |
| 80 | +-- Set time zone to server value (not user value !) |
| 81 | +set time zone local; |
| 82 | +``` |
| 83 | + |
| 84 | +### Show session time zone |
| 85 | + |
| 86 | +```sql |
| 87 | +select TimeZoneString from "DBC".SessionInfoVX where SessionNo = session |
| 88 | +``` |
| 89 | + |
| 90 | +## List of the time zones |
| 91 | + |
| 92 | +[List from Teradata documentation](https://docs.teradata.com/r/w19R4KsuHIiEqyxz0WYfgA/67rSW_MQwBiVQ3siO~dt7Q) |
| 93 | + |
| 94 | +## Using time zones |
| 95 | + |
| 96 | +Let's try with examples: |
| 97 | + |
| 98 | +### Timestamp without time zone |
| 99 | + |
| 100 | +```sql |
| 101 | +create volatile table tb_without_tz (ts_without_tz timestamp(0)) on commit preserve rows; |
| 102 | +-- Here, we assume that the session time zone is the same as the server 'Europe Central' in this case. |
| 103 | +ins tb_without_tz values ('2021-04-28 10:00:00'); |
| 104 | +select * from tb_without_tz; |
| 105 | +-- Shows 2021-04-28 10:00:00 |
| 106 | + |
| 107 | +set time zone 'America Eastern'; |
| 108 | +select * from tb_without_tz; |
| 109 | +-- Shows 2021-04-28 04:00:00 |
| 110 | +``` |
| 111 | + |
| 112 | +As you can see, even if the field is defined **without** time zone, the output depends on the session time zone. This can be very confusing and that's why it is recommended to keep user/session time zone unset. |
| 113 | + |
| 114 | +#### Set a time zone different from the server before inserting |
| 115 | + |
| 116 | +```sql |
| 117 | +del tb_without_tz; |
| 118 | +set time zone 'America Eastern'; |
| 119 | +ins tb_without_tz values ('2021-04-28 10:00:00'); |
| 120 | +select * from tb_without_tz; |
| 121 | +-- Shows 2021-04-28 10:00:00 |
| 122 | + |
| 123 | +-- Set back session time zone to server value |
| 124 | +set time zone local; |
| 125 | +select * from tb_without_tz; |
| 126 | +-- Shows 2021-04-28 16:00:00 |
| 127 | +``` |
| 128 | + |
| 129 | +#### Conclusion |
| 130 | + |
| 131 | +When working on timestamp without time zone: |
| 132 | + |
| 133 | +- when inserting, teradata convert the timestamp from the session time zone to the server time zone |
| 134 | + |
| 135 | +- when selecting, teradata convert the timestamp from the server time zone to the session time zone |
0 commit comments