Join us on YugabyteDB Community Slack
Star us on
Get Started
Slack
GitHub
Get Started
v2.13 (latest) v2.12 (stable) v2.8 (earlier version) v2.6 (earlier version) v2.4 (earlier version) v2.2 (earlier version) v2.1 (earlier version) v2.0 (earlier version) v1.3 (earlier version)
  • YUGABYTEDB CORE
    • Quick start
      • 1. Install YugabyteDB
      • 2. Create a local cluster
      • 3. Explore distributed SQL
      • 4. Build an application
        • Java
        • Node.js
        • Go
        • Python
        • Ruby
        • C#
        • PHP
        • C++
        • C
        • Scala
    • Explore
      • SQL features
        • Schemas and Tables
        • Data Types
        • Data Manipulation
        • Queries and Joins
        • Expressions and Operators
        • Stored Procedures
        • Triggers
        • Advanced features
          • Cursors
          • Table Partitioning
          • Views
          • Savepoints
          • Collations
          • Extensions
        • Going beyond SQL
          • Follower reads
          • Tablespaces
      • Fault tolerance
      • Horizontal scalability
        • Scaling Transactions
        • Sharding Data
      • Transactions
        • Distributed Transactions
        • Isolation Levels
        • Explicit Locking
      • Indexes and Constraints
        • Overview
        • Unique Indexes
        • Partial Indexes
        • Expression Indexes
        • Generalized Inverted Indexes
        • Primary Key
        • Foreign Key
        • Other Constraints
      • JSON support
      • Multi-region deployments
        • Sync replication (3+ regions)
        • Async Replication (2+ regions)
        • Row-Level Geo-Partitioning
        • Read replicas
      • Query tuning
        • Introduction
        • Get query statistics using pg_stat_statements
        • Viewing live queries with pg_stat_activity
        • Analyzing queries with EXPLAIN
        • Optimizing YSQL queries using pg_hint_plan
      • Cluster management
        • Point-in-time recovery
      • Security
      • Observability
        • Prometheus Integration
        • Grafana Dashboard
    • Develop
      • Learn app development
        • 1. SQL vs NoSQL
        • 2. Data modeling
        • 3. Data types
        • 4. ACID transactions
        • 5. Aggregations
        • 6. Batch operations
        • 7. Date and time
        • 8. Strings and text
        • 9. TTL for data expiration
      • Real-world examples
        • E-Commerce app
        • IoT fleet management
      • Explore sample apps
      • Best practices
      • Cloud-native development
        • Codespaces
        • Gitpod
    • Migrate
      • Migration process overview
      • Migrate from PostgreSQL
        • Convert a PostgreSQL schema
        • Migrate a PostgreSQL application
        • Export PostgreSQL data
        • Prepare a cluster
        • Import PostgreSQL data
        • Verify Migration
    • Deploy
      • Deployment checklist
      • Manual deployment
        • 1. System configuration
        • 2. Install software
        • 3. Start YB-Masters
        • 4. Start YB-TServers
        • 5. Verify deployment
      • Kubernetes
        • Single-zone
          • Open Source
          • Amazon EKS
          • Google Kubernetes Engine
          • Azure Kubernetes Service
        • Multi-zone
          • Amazon EKS
          • Google Kubernetes Engine
        • Multi-cluster
          • Google Kubernetes Engine
        • Best practices
        • Connect Clients
      • Docker
      • Public clouds
        • Amazon Web Services
        • Google Cloud Platform
        • Microsoft Azure
      • Multi-DC deployments
        • Three+ data center (3DC)
        • Asynchronous Replication
        • Read replica clusters
    • Benchmark
      • TPC-C
      • sysbench
      • YCSB
      • Key-value workload
      • Large datasets
      • Scalability
        • Scaling queries
      • Resilience
        • Jepsen testing
      • Performance Troubleshooting
    • Secure
      • Security checklist
      • Enable Authentication
        • Enable User Authentication
        • Configure ysql_hba_conf_csv
      • Authentication Methods
        • Password Authentication
        • LDAP Authentication
        • Host-Based Authentication
        • Trust Authentication
      • Role-Based Access Control
        • Overview
        • Manage Users and Roles
        • Grant Privileges
        • Row-Level Security (RLS)
        • Column-Level Security
      • Encryption in Transit
        • Create server certificates
        • Enable server-to-server encryption
        • Enable client-to-server encryption
        • Connect to Clusters
        • TLS and authentication
      • Encryption at rest
      • Column-level encryption
      • Audit Logging
        • Configure Audit Logging
        • Session-Level Audit Logging
        • Object-Level Audit Logging
      • Vulnerability disclosure policy
    • Manage
      • Back up and restore
        • Back up data
        • Restore data
        • Point-in-time recovery
        • Snapshot and restore data
      • Migrate data
        • Bulk import
        • Bulk export
      • Change cluster configuration
      • Diagnostics reporting
      • Upgrade a deployment
      • Grow cluster
    • Troubleshoot
      • Troubleshooting
      • Cluster level issues
        • YCQL connection issues
        • YEDIS connection Issues
        • Recover tserver/master
        • Replace a failed YB-TServer
        • Replace a failed YB-Master
        • Manual remote bootstrap when a majority of peers fail
      • Node level issues
        • Check servers
        • Inspect logs
        • System statistics
        • Disk failure
        • Common error messages
    • Contribute
      • Core database
        • Contribution checklist
        • Build the source
        • Configure a CLion project
        • Run the tests
        • Coding style
  • YUGABYTE PLATFORM
    • Overview
      • Install
      • Configure
    • Install Yugabyte Platform
      • Prerequisites
      • Prepare the environment
      • Install software
      • Prepare nodes (on-prem)
      • Uninstall software
    • Configure Yugabyte Platform
      • Create admin user
      • Configure the cloud provider
      • Configure the backup target
      • Configure alerts
    • Create deployments
      • Multi-zone universe
      • Multi-region universe
      • Multi-cloud universe
      • Read replica cluster
      • Asynchronous replication
    • Manage deployments
      • Start and stop processes
      • Add a node
      • Eliminate an unresponsive node
      • Enable high availability
      • Edit configuration flags
      • Edit a universe
      • Delete a universe
      • Configure instance tags
      • Upgrade YugabyteDB software
      • Migrate to Helm 3
    • Back up universes
      • Configure backup storage
      • Back up universe data
      • Restore universe data
      • Schedule data backups
    • Security
      • Security checklist
      • Customize ports
      • LDAP authentication
      • Authorization platform
      • Create a KMS configuration
      • Enable encryption at rest
      • Enable encryption in transit (TLS)
      • Network security
    • Alerts and monitoring
      • Alerts
      • Live Queries dashboard
      • Slow Queries dashboard
    • Troubleshoot
      • Install and upgrade issues
      • Universe issues
    • Administer Yugabyte Platform
      • Back Up Yugabyte Platform
      • Authenticate with LDAP
    • Upgrade Yugabyte Platform
      • Upgrade using Replicated
  • YUGABYTE CLOUD
    • Overview
    • Quick start
      • Create a free cluster
      • Connect to the cluster
      • Create a database
      • Explore distributed SQL
      • Build an application
        • Before you begin
        • Java
        • Go
        • Python
        • Node.js
        • C
        • C++
        • C#
        • Ruby
        • Rust
        • PHP
    • Deploy clusters
      • Planning a cluster
      • Create a free cluster
      • Create a standard cluster
      • VPC network
        • Overview
        • Set up a VPC network
        • VPCs
        • Peering Connections
    • Secure clusters
      • IP allow lists
      • Database authorization
      • Add database users
      • Encryption in transit
      • Audit cloud activity
    • Connect to clusters
      • Cloud Shell
      • Client shell
      • Connect applications
    • Alerts and monitoring
      • Alerts
      • Performance metrics
      • Live queries
      • Slow YSQL queries
      • Cluster activity
    • Manage clusters
      • Backup and restore
      • Scale and configure clusters
      • Create extensions
    • Administer Yugabyte Cloud
      • Manage cloud users
      • Manage billing
      • Cluster costs
    • Example applications
      • Connect a Spring application
      • Connect a YCQL Java application
      • Hasura Cloud
      • Deploy a GraphQL application
    • Security architecture
      • Security architecture
      • Shared responsibility model
    • Troubleshoot
    • Yugabyte Cloud FAQ
    • What's new
  • INTEGRATIONS
    • Apache Kafka
    • Apache Spark
    • JanusGraph
    • KairosDB
    • Presto
    • Metabase
    • WSO2 Identity Server
    • YSQL Loader
    • Yugabyte JDBC Driver
    • Prisma
    • Hasura
      • Application Development
      • Benchmarking
    • Spring Framework
      • Spring Data YugabyteDB
      • Spring Data Cassandra
    • Flyway
    • GORM
    • Liquibase
    • Sequelize
    • SQLAlchemy
    • Entity Framework
    • Django REST framework
  • REFERENCE
    • Architecture
      • Design goals
      • Key concepts
        • Universe
        • YB-TServer Service
        • YB-Master Service
      • Core functions
        • Universe creation
        • Table creation
        • Write IO path
        • Read IO path
        • High availability
      • Layered architecture
      • Query layer
        • Overview
      • DocDB transactions layer
        • Transactions overview
        • Transaction isolation levels
        • Explicit locking
        • Read Committed
        • Single-row transactions
        • Distributed transactions
        • Transactional IO path
      • DocDB sharding layer
        • Hash & range sharding
        • Tablet splitting
        • Colocated tables
      • DocDB replication layer
        • Replication
        • xCluster replication
        • Read replicas
        • Change data capture (CDC)
      • DocDB storage layer
        • Persistence
        • Performance
    • APIs
      • YSQL
        • The SQL language
          • SQL statements
            • ABORT
            • ALTER DATABASE
            • ALTER DEFAULT PRIVILEGES
            • ALTER DOMAIN
            • ALTER GROUP
            • ALTER POLICY
            • ALTER ROLE
            • ALTER SEQUENCE
            • ALTER TABLE
            • ALTER USER
            • ANALYZE
            • BEGIN
            • CALL
            • COMMENT
            • COMMIT
            • COPY
            • CREATE AGGREGATE
            • CREATE CAST
            • CREATE DATABASE
            • CREATE DOMAIN
            • CREATE EXTENSION
            • CREATE FUNCTION
            • CREATE GROUP
            • CREATE INDEX
            • CREATE MATERIALIZED VIEW
            • CREATE OPERATOR
            • CREATE OPERATOR CLASS
            • CREATE POLICY
            • CREATE PROCEDURE
            • CREATE ROLE
            • CREATE RULE
            • CREATE SCHEMA
            • CREATE SEQUENCE
            • CREATE TABLE
            • CREATE TABLE AS
            • CREATE TRIGGER
            • CREATE TYPE
            • CREATE USER
            • CREATE VIEW
            • DEALLOCATE
            • DELETE
            • DO
            • DROP AGGREGATE
            • DROP CAST
            • DROP DATABASE
            • DROP DOMAIN
            • DROP EXTENSION
            • DROP FUNCTION
            • DROP GROUP
            • DROP MATERIALIZED VIEW
            • DROP OPERATOR
            • DROP OPERATOR CLASS
            • DROP OWNED
            • DROP POLICY
            • DROP PROCEDURE
            • DROP ROLE
            • DROP RULE
            • DROP SEQUENCE
            • DROP TABLE
            • DROP TRIGGER
            • DROP TYPE
            • DROP USER
            • END
            • EXECUTE
            • EXPLAIN
            • GRANT
            • INSERT
            • LOCK
            • PREPARE
            • REASSIGN OWNED
            • REFRESH MATERIALIZED VIEW
            • RELEASE SAVEPOINT
            • RESET
            • REVOKE
            • ROLLBACK
            • ROLLBACK TO SAVEPOINT
            • SAVEPOINT
            • SELECT
            • SET
            • SET CONSTRAINTS
            • SET ROLE
            • SET SESSION AUTHORIZATION
            • SET TRANSACTION
            • SHOW
            • SHOW TRANSACTION
            • TRUNCATE
            • UPDATE
            • VALUES
          • WITH clause
            • WITH clause—SQL syntax and semantics
            • recursive CTE
            • case study—traversing an employee hierarchy
            • traversing general graphs
              • graph representation
              • common code
              • undirected cyclic graph
              • directed cyclic graph
              • directed acyclic graph
              • rooted tree
              • Unique containing paths
              • Stress testing find_paths()
            • case study—Bacon Numbers from IMDb
              • Bacon numbers for synthetic data
              • Bacon numbers for IMDb data
        • Data types
          • Array
            • array[] constructor
            • Literals
              • Text typecasting and literals
              • Array of primitive values
              • Row
              • Array of rows
            • FOREACH loop (PL/pgSQL)
            • array of DOMAINs
            • Functions and operators
              • ANY and ALL
              • Array comparison
              • Array slice operator
              • Array concatenation
              • Array properties
              • array_agg(), unnest(), generate_subscripts()
              • array_fill()
              • array_position(), array_positions()
              • array_remove()
              • array_replace() / set value
              • array_to_string()
              • string_to_array()
          • Binary
          • Boolean
          • Character
          • Date and time
            • Conceptual background
            • Timezones and UTC offsets
              • Catalog views
              • Extended_timezone_names
                • Unrestricted full projection
                • Real timezones with DST
                • Real timezones no DST
                • Synthetic timezones no DST
              • Offset/timezone-sensitive operations
                • Timestamptz to/from timestamp conversion
                • Pure 'day' interval arithmetic
              • Four ways to specify offset
                • Name-resolution rules
                  • 1 case-insensitive resolution
                  • 2 ~names.abbrev never searched
                  • 3 'set timezone' string not resolved in ~abbrevs.abbrev
                  • 4 ~abbrevs.abbrev before ~names.name
                  • Helper functions
              • Syntax contexts for offset
              • Recommended practice
            • Typecasting between date-time and text-values
            • Semantics of the date-time data types
              • Date data type
              • Time data type
              • Plain timestamp and timestamptz
              • Interval data type
                • Interval representation
                  • Ad hoc examples
                  • Representation model
                • Interval value limits
                • Declaring intervals
                • Justify() and extract(epoch...)
                • Interval arithmetic
                  • Interval-interval comparison
                  • Interval-interval addition and subtraction
                  • Interval-number multiplication
                  • Moment-moment overloads of "-"
                  • Moment-interval overloads of "+" and "-"
                • Custom interval domains
                • Interval utility functions
            • Typecasting between date-time datatypes
            • Operators
              • Test comparison overloads
              • Test addition overloads
              • Test subtraction overloads
              • Test multiplication overloads
              • Test division overloads
            • General-purpose functions
              • Creating date-time values
              • Manipulating date-time values
              • Current date-time moment
              • Delaying execution
              • Miscellaneous
                • Function age()
                • Function extract() | date_part()
                • Implementations that model the overlaps operator
            • Formatting functions
            • Case study—SQL stopwatch
            • Download & install the date-time utilities
            • ToC
          • JSON
            • JSON literals
            • Primitive and compound data types
            • Code example conventions
            • Indexes and check constraints
            • Functions & operators
              • ::jsonb, ::json, ::text (typecast)
              • ->, ->>, #>, #>> (JSON subvalues)
              • - and #- (remove)
              • || (concatenation)
              • = (equality)
              • @> and <@ (containment)
              • ? and ?| and ?& (key or value existence)
              • array_to_json()
              • jsonb_agg()
              • jsonb_array_elements()
              • jsonb_array_elements_text()
              • jsonb_array_length()
              • jsonb_build_object()
              • jsonb_build_array()
              • jsonb_each()
              • jsonb_each_text()
              • jsonb_extract_path()
              • jsonb_extract_path_text() and json_extract_path_text()
              • jsonb_object()
              • jsonb_object_agg()
              • jsonb_object_keys()
              • jsonb_populate_record()
              • jsonb_populate_recordset()
              • jsonb_pretty()
              • jsonb_set() and jsonb_insert()
              • jsonb_strip_nulls()
              • jsonb_to_record()
              • jsonb_to_recordset()
              • jsonb_typeof()
              • row_to_json()
              • to_jsonb()
          • Money
          • Numeric
          • Range
          • Serial
          • UUID
        • Functions and operators
          • Aggregate functions
            • Informal functionality overview
            • Invocation syntax and semantics
            • grouping sets, rollup, cube
            • Per function signature and purpose
              • avg(), count(), max(), min(), sum()
              • array_agg(), string_agg(), jsonb_agg(), jsonb_object_agg()
              • bit_and(), bit_or(), bool_and(), bool_or()
              • variance(), var_pop(), var_samp(), stddev(), stddev_pop(), stddev_samp()
              • linear regression
                • covar_pop(), covar_samp(), corr()
                • regr_%()
              • mode(), percentile_disc(), percentile_cont()
              • rank(), dense_rank(), percent_rank(), cume_dist()
            • case study—percentile_cont() and the "68–95–99.7" rule
            • case study—linear regression on COVID data
              • Download the COVIDcast data
              • Ingest the COVIDcast data
                • Inspect the COVIDcast data
                • Copy the .csv files to staging tables
                • Check staged data conforms to the rules
                • Join the staged data into a single table
                • SQL scripts
                  • Create cr_staging_tables()
                  • Create cr_copy_from_scripts()
                  • Create assert_assumptions_ok()
                  • Create xform_to_covidcast_fb_survey_results()
                  • ingest-the-data.sql
              • Analyze the COVIDcast data
                • symptoms vs mask-wearing by day
                • Data for scatter-plot for 21-Oct-2020
                • Scatter-plot for 21-Oct-2020
                • SQL scripts
                  • analysis-queries.sql
                  • synthetic-data.sql
          • currval()
          • lastval()
          • nextval()
          • Window functions
            • Informal functionality overview
            • Invocation syntax and semantics
            • Per function signature and purpose
              • row_number(), rank() and dense_rank()
              • percent_rank(), cume_dist() and ntile()
              • first_value(), nth_value(), last_value()
              • lag(), lead()
              • Tables for the code examples
                • table t1
                • table t2
                • table t3
                • table t4
            • case study—analyzing a normal distribution
              • Bucket allocation scheme
              • do_clean_start.sql
              • cr_show_t4.sql
              • cr_dp_views.sql
              • cr_int_views.sql
              • cr_pr_cd_equality_report.sql
              • cr_bucket_using_width_bucket.sql
              • cr_bucket_dedicated_code.sql
              • do_assert_bucket_ok
              • cr_histogram.sql
              • cr_do_ntile.sql
              • cr_do_percent_rank.sql
              • cr_do_cume_dist.sql
              • do_populate_results.sql
              • do_report_results.sql
              • do_compare_dp_results.sql
              • do_demo.sql
              • Reports
                • Histogram report
                • dp-results
                • compare-dp-results
                • int-results
          • yb_hash_code()
        • Extensions
        • Keywords
        • Reserved names
      • YCQL
        • ALTER KEYSPACE
        • ALTER ROLE
        • ALTER TABLE
        • CREATE INDEX
        • CREATE KEYSPACE
        • CREATE ROLE
        • CREATE TABLE
        • CREATE TYPE
        • DROP INDEX
        • DROP KEYSPACE
        • DROP ROLE
        • DROP TABLE
        • DROP TYPE
        • GRANT PERMISSION
        • GRANT ROLE
        • REVOKE PERMISSION
        • REVOKE ROLE
        • USE
        • INSERT
        • SELECT
        • EXPLAIN
        • UPDATE
        • DELETE
        • TRANSACTION
        • TRUNCATE
        • Simple expressions
        • Subscripted expressions
        • Function call
        • Operators
        • BLOB
        • BOOLEAN
        • Collection
        • FROZEN
        • INET
        • Integer and counter
        • Non-integer
        • TEXT
        • DATE, TIME, and TIMESTAMP
        • UUID and TIMEUUID
        • JSONB
        • Date and time
        • BATCH
    • CLIs
      • yb-ctl
      • yb-docker-ctl
      • ysqlsh
      • ycqlsh
      • yb-admin
      • yb-ts-cli
      • ysql_dump
      • ysql_dumpall
    • Configuration
      • yb-tserver
      • yb-master
      • yugabyted
      • Default ports
    • Drivers
      • Client drivers for YSQL
      • Client drivers for YCQL
    • Connectors
      • Kafka Connect YugabyteDB
    • Third party tools
      • Arctype
      • DBeaver
      • DbSchema
      • pgAdmin
      • SQL Workbench/J
      • TablePlus
      • Visual Studio Code
    • Sample datasets
      • Chinook
      • Northwind
      • PgExercises
      • SportsDB
      • Retail Analytics
  • RELEASES
    • Releases overview
      • v2.13 series (latest)
      • v2.12 series (stable)
      • v2.11 series
      • v2.9 series
      • v2.8 series
      • v2.7 series
      • v2.6 series
      • v2.5 series
      • v2.4 series
      • v2.3 series
      • v2.2 series
      • v2.1 series
      • v2.0 series
      • v1.3 series
      • v1.2 series
    • Release versioning
  • FAQ
    • Comparisons
      • Amazon Aurora
      • Google Cloud Spanner
      • CockroachDB
      • TiDB
      • Vitess
      • MongoDB
      • FoundationDB
      • Amazon DynamoDB
      • Azure Cosmos DB
      • Apache Cassandra
      • PostgreSQL
      • Redis in-memory store
      • Apache HBase
    • General FAQ
    • Operations FAQ
    • API compatibility FAQ
    • Yugabyte Platform FAQ
  • MISC
    • YEDIS
      • Quick start
      • Develop
        • Build an application
        • C#
        • C++
        • Go
        • Java
        • NodeJS
        • Python
      • API reference
        • APPEND
        • AUTH
        • CONFIG
        • CREATEDB
        • DELETEDB
        • LISTDB
        • SELECT
        • DEL
        • ECHO
        • EXISTS
        • EXPIRE
        • EXPIREAT
        • FLUSHALL
        • FLUSHDB
        • GET
        • GETRANGE
        • GETSET
        • HDEL
        • HEXISTS
        • HGET
        • HGETALL
        • HINCRBY
        • HKEYS
        • HLEN
        • HMGET
        • HMSET
        • HSET
        • HSTRLEN
        • HVALS
        • INCR
        • INCRBY
        • KEYS
        • MONITOR
        • PEXPIRE
        • PEXPIREAT
        • PTTL
        • ROLE
        • SADD
        • SCARD
        • RENAME
        • SET
        • SETEX
        • PSETEX
        • SETRANGE
        • SISMEMBER
        • SMEMBERS
        • SREM
        • STRLEN
        • ZRANGE
        • TSADD
        • TSCARD
        • TSGET
        • TSLASTN
        • TSRANGEBYTIME
        • TSREM
        • TSREVRANGEBYTIME
        • TTL
        • ZADD
        • ZCARD
        • ZRANGEBYSCORE
        • ZREM
        • ZREVRANGE
        • ZSCORE
        • PUBSUB
        • PUBLISH
        • SUBSCRIBE
        • UNSUBSCRIBE
        • PSUBSCRIBE
        • PUNSUBSCRIBE
    • Legal
      • Third party software
> APIs > YSQL > Data types > Date and time > Timezones and UTC offsets >

Recommended practice for specifying the UTC offset

Report a doc issue Suggest new content
  • The approved_timezone_names view
  • Common procedures to assert the approval of a timezone name and an interval value
    • assert_approved_timezone_name()
    • assert_acceptable_timezone_interval()
  • The set_timezone() procedure overloads
  • The at_timezone() function overloads
  • Test the set_timezone() and the at_timezone() overloads
    • Test the set_timezone(text) overload
    • Test the set_timezone(interval) overload
    • Test the at_timezone(text, timestamp) overload
    • Test the at_timezone(interval, timestamp) overload

Write user-defined functions to wrap 'set timezone' and the overloads of the built-in function 'timezone()'.

Yugabyte recommends that you create two user-defined function overload sets, thus:

  • set_timezone(), with (text) and (interval) overloads to wrap set timezone to ensure that safe, approved arguments are used.

  • at_timezone() with (text, timestamp), (interval, timestamp), (text, timestamptz), (interval, timestamptz) overloads to wrap the corresponding overloads of the timezone() built-in function to ensure that safe, approved arguments are used.

"Safe, approved arguments" means:

  • When a timezone is specified using its name, this is checked against a list of approved names—a subset of the rows in pg_timezone_names.name
  • When a timezone is specified using an interval value, this is checked to ensure that it lies in the range defined by the overall maximum and minimum values of utc_offset columns in the pg_timezone_names and pg_timezone_abbrevs catalog views. It's also checked to ensure that it's an integral multiple of fifteen minutes, respecting the convention followed by every timezone shown by pg_timezone_names.

Following these recommendations protects you from the many opportunities to go wrong brought by using the native functionality with no constraints; and yet doing so still allows you all the functionality that you could need.


Download and install the date-time utilities code.

The code on this page depends on the extended_timezone_names view. It also depends on the custom interval domains code. And this, in turn, depends on the user-defined interval utilities.

These components are all included in the larger code kit that includes all of the reusable code that the overall date-time section describes and uses.

The code on that this page defines is intended for reuse. It, too, is therefore included in the date-time utilities downloadable code kit.

The approved_timezone_names view

This is the union of the Real timezones that observe Daylight Savings Time view, the Real timezones that don't observe Daylight Savings Time view, and the single row that specifies the facts about the UTC Time Standard.

drop view if exists approved_timezone_names cascade;

create view approved_timezone_names as
select
  name,
  std_abbrev,
  dst_abbrev,
  std_offset,
  dst_offset
from extended_timezone_names
where
  name = 'UTC'

  or

  (
    lower(status) = 'canonical'                                        and
    country_code is not null                                           and
    country_code <> ''                                                 and
    lat_long is not null                                               and
    lat_long <> ''                                                     and

    name not like '%0%'                                                and
    name not like '%1%'                                                and
    name not like '%2%'                                                and
    name not like '%3%'                                                and
    name not like '%4%'                                                and
    name not like '%5%'                                                and
    name not like '%6%'                                                and
    name not like '%7%'                                                and
    name not like '%8%'                                                and
    name not like '%9%'                                                and

    lower(name) not in (select lower(abbrev) from pg_timezone_names)   and
    lower(name) not in (select lower(abbrev) from pg_timezone_abbrevs)
  );

Common procedures to assert the approval of a timezone name and an interval value

These two "assert" procedures are used by both the set_timezone() and the at_timezone() user-defined function overloads. They depend upon some code described in the section Custom domain types for specializing the native interval functionality. And these, in turn, depend on some code described in the User-defined interval utility functions section.

assert_approved_timezone_name()

drop procedure if exists assert_approved_timezone_name(text) cascade;

create procedure assert_approved_timezone_name(tz in text)
  language plpgsql
as $body$
declare
  bad constant boolean not null :=
    (select count(*) from approved_timezone_names where lower(name) = lower(tz)) <> 1;
begin
  if bad then
    declare
      code  constant text not null := '22023';
      msg   constant text not null := 'Invalid value for parameter TimeZone "'||tz||'"';
      hint  constant text not null := 'Use a name that''s found exactly once in "approved_timezone_names"';
    begin
      raise exception using
        errcode = code,
        message = msg,
        hint    = hint;
    end;
  end if;
end;
$body$;

assert_acceptable_timezone_interval()

drop procedure if exists assert_acceptable_timezone_interval(interval) cascade;

create procedure assert_acceptable_timezone_interval(i in interval)
  language plpgsql
as $body$
declare
  min_utc_offset constant interval not null := (
    select least(
        (select min(utc_offset) from pg_timezone_names),
        (select min(utc_offset) from pg_timezone_abbrevs)
      )
    );

  max_utc_offset constant interval not null := (
    select greatest(
        (select max(utc_offset) from pg_timezone_names),
        (select max(utc_offset) from pg_timezone_abbrevs)
      )
    );

  -- Check that the values are "pure seconds" intervals.
  min_i constant interval_seconds_t not null := min_utc_offset;
  max_i constant interval_seconds_t not null := max_utc_offset;

  -- The interval value must not have a seconds component.
  bad constant boolean not null :=
    not(
        (i between min_i and max_i) and
        (extract(seconds from i) = 0.0)
      );
begin
  if bad then
    declare
      code  constant text not null := '22023';
      msg   constant text not null := 'Invalid value for interval: "'||i::text||'"';
      hint  constant text not null := 'Use a value between "'||min_i||'" and "'||max_i||'" with seconds cpt = zero';
    begin
      raise exception using
        errcode = code,
        message = msg,
        hint    = hint;
    end;
  end if;
end;
$body$;

Should you be concerned about the performance of this check, you can rely on the fact that the limits for acceptable interval values that it discovers on every invocation can simply be declared as constants in the functions source code. The safest way to do this is to write a generator procedure to create [or replace] the assert_acceptable_timezone_interval() procedure and to document the practice that requires that this generator be run whenever the YugabyteDB version (or the PostgreSQL version) is created or changed. (Your practice rule would need to be stated more carefully if you allow changes to the configuration files that determine the contents that the pg_timezone_names view and the pg_timezone_abbrevs view expose.)

The set_timezone() procedure overloads

drop procedure if exists set_timezone(text) cascade;

create procedure set_timezone(tz in text)
  language plpgsql
as $body$
begin
  call assert_approved_timezone_name(tz);
  declare
    stmt constant text not null := 'set timezone = '''||tz||'''';
  begin
    execute stmt;
  end;
end;
$body$;


drop procedure if exists set_timezone(interval) cascade;

create procedure set_timezone(i in interval)
  language plpgsql
as $body$
begin
  call assert_acceptable_timezone_interval(i);
  declare
    stmt constant text not null := 'set time zone interval '''||i::text||'''';
  begin
    execute stmt;
  end;
end;
$body$;

The at_timezone() function overloads

Do this to see the overloads of interest of the timezone() built-in function.

\df timezone()

This is the result:

      Result data type       |          Argument data types
-----------------------------+--------------------------------------
 ...
 timestamp without time zone | interval, timestamp with time zone
 timestamp with time zone    | interval, timestamp without time zone
 ...
 timestamp without time zone | text, timestamp with time zone
 timestamp with time zone    | text, timestamp without time zone

(The output also lists overloads for the timetz data type. This has been elided because, following the PostgreSQL documentation, Yugabyte recommends that you don't use this data type.)

Create wrapper functions for the four listed built-in functions:

-- plain timestamp in, timestamptz out.
drop function if exists at_timezone(text, timestamp) cascade;

create function at_timezone(tz in text, t in timestamp)
  returns timestamptz
  language plpgsql
as $body$
begin
  call assert_approved_timezone_name(tz);
  return timezone(tz, t);
end;
$body$;

-- This overload is almost textually identical to the preceding one.
-- The data types of the second formal and the return have
-- simply been exchanged.
-- timestamptz in, plain timestamp out.
drop function if exists at_timezone(text, timestamptz) cascade;

create function at_timezone(tz in text, t in timestamptz)
  returns timestamp
  language plpgsql
as $body$
begin
  call assert_approved_timezone_name(tz);
  return timezone(tz, t);
end;
$body$;

-- interval in, timestamptz out.
drop function if exists at_timezone(interval, timestamp) cascade;

create function at_timezone(i in interval, t in timestamp)
  returns timestamptz
  language plpgsql
as $body$
begin
  call assert_acceptable_timezone_interval(i);
  return timezone(i, t);
end;
$body$;

-- This overload is almost textually identical to the preceding one.
-- The data types of the second formal and the return have
-- simply been exchanged.
-- interval in, plain timestamp out.
drop function if exists at_timezone(interval, timestamptz) cascade;

create function at_timezone(i in interval, t in timestamptz)
  returns timestamp
  language plpgsql
as $body$
begin
  call assert_acceptable_timezone_interval(i);
  return timezone(i, t);
end;
$body$;

Test the set_timezone() and the at_timezone() overloads

The following tests contain some commented out raise info statements. They show the error messages that you get when you supply a timezone name that isn't approved or, or an interval value that isn't acceptable.

Test the set_timezone(text) overload

Do this:

do $body$
declare
  tz_in  text not null := '';
  tz_out text not null := '';

  good_zones constant text[] := array[
    'UTC',
    'Asia/Kathmandu',
    'Europe/Amsterdam'];
begin
  foreach tz_in in array good_zones loop
    call set_timezone(tz_in);
    show timezone into tz_out;
    declare
      msg constant text not null := tz_in||' assert failed';
    begin
      assert tz_out = tz_in, msg;
    end;
  end loop;

  begin
    call set_timezone('Bad');
    assert false, 'Logic error';
  exception when invalid_parameter_value then
    declare
      msg  text not null := '';
      hint text not null := '';
    begin
      get stacked diagnostics
        msg     = message_text,
        hint    = pg_exception_hint;

      /*
      raise info '%', msg;
      raise info '%', hint;
      */
    end;
  end;
end;
$body$;

The block finishes silently, showing that all of the assertions hold. Uncomment the raise info statements and repeat the test. You'll see this information:

INFO:  Invalid value for parameter TimeZone "Bad"
INFO:  Use a name that's found exactly once in "approved_timezone_names"

Test the set_timezone(interval) overload

Do this:

do $body$
declare
  tz_out text not null := '';
begin
  call set_timezone(make_interval(hours=>-7));
  show timezone into tz_out;
  assert tz_out= '<-07>+07', 'Assert <-07>+07 failed';

  call set_timezone(make_interval(hours=>-5, mins=>45));
  show timezone into tz_out;
  assert tz_out= '<-04:15>+04:15', 'Assert <-04:15>+04:15 failed';

  begin
    call set_timezone(make_interval(hours=>19));
    assert false, 'Logic error';
  exception when invalid_parameter_value then
    declare
      msg  text not null := '';
      hint text not null := '';
    begin
      get stacked diagnostics
        msg     = message_text,
        hint    = pg_exception_hint;

      /*
      raise info '%', msg;
      raise info '%', hint;
      */
    end;
  end;
end;
$body$;

The block finishes silently, showing that all of the assertions hold. Uncomment the raise info statements and repeat the test. You'll see this information:

INFO:  Invalid value for interval "19:00:00"
INFO:  Use a value between "-12:00:00" and "14:00:00"

Test the at_timezone(text, timestamp) overload

Do this:

do $body$
declare
  t_text       constant text        not null := '2021-05-31 12:00:00';
  t_plain      constant timestamp   not null := t_text;
  tz_result             timestamptz not null := t_text||' UTC'; -- Satisfy the constraints.
  tz_expected           timestamptz not null := t_text||' UTC'; -- The values will be overwritten
  tz                    text        not null := '';

  good_zones constant text[] := array[
    'UTC',
    'Asia/Kathmandu',
    'Europe/Amsterdam'];
begin
  foreach tz in array good_zones loop
    tz_result   := at_timezone(tz, t_plain);
    tz_expected := t_text||' '||tz;

    declare
      msg constant text not null := tz||' assert failed';
    begin
      assert tz_result = tz_expected, msg;
    end;
  end loop;
end;
$body$;

The block finishes silently, showing that all of the assertions hold. There's no value in including a bad-value negative test because doing so would simply be a repeat, and therefore redundant, test of the assert_approved_timezone_name() procedure.

Test the at_timezone(interval, timestamp) overload

Do this:

do $body$
declare
  t_text       constant text        not null := '2021-05-31 12:00:00';
  t_plain      constant timestamp   not null := t_text;
  tz_result             timestamptz not null := t_text||' UTC'; -- Satisfy the constraints.
  tz_expected           timestamptz not null := t_text||' UTC'; -- The values will be overwritten
  i                     interval    not null := make_interval();
  hh                    text        not null := 0;
  mm                    text        not null := 0;

  i_vals       constant interval[]  not null := array[
                                                    make_interval(),
                                                    make_interval(hours=>4, mins=>30),
                                                    make_interval(hours=>-7)
                                                  ];
begin
  foreach i in array i_vals loop
    hh := ltrim(to_char(extract(hour   from i), 'SG09')); -- Essential to prefix with the sign.
    mm := ltrim(to_char(extract(minute from i), '09'));
    tz_result   := at_timezone(i, t_plain);
    tz_expected := t_text||' '||hh||':'||mm;
    declare
      msg constant text not null := i::text||' assert failed';
    begin
      assert tz_result = tz_expected, msg;
    end;
  end loop;
end;
$body$;

The block finishes silently, showing that all of the assertions hold. There's no value in including a bad-value negative test because doing so would simply be a repeat, and therefore redundant, test of the assert_acceptable_timezone_interval() procedure.

  • The approved_timezone_names view
  • Common procedures to assert the approval of a timezone name and an interval value
    • assert_approved_timezone_name()
    • assert_acceptable_timezone_interval()
  • The set_timezone() procedure overloads
  • The at_timezone() function overloads
  • Test the set_timezone() and the at_timezone() overloads
    • Test the set_timezone(text) overload
    • Test the set_timezone(interval) overload
    • Test the at_timezone(text, timestamp) overload
    • Test the at_timezone(interval, timestamp) overload
Ask our community
  • Slack
  • Github
  • Forum
  • StackOverflow
Yugabyte
Contact Us
Copyright © 2017-2022 Yugabyte, Inc. All rights reserved.