Join us on YugabyteDB Community Slack
Star us on
Get Started
Slack
GitHub
Get Started
v2.13 (preview) v2.12 (stable) v2.8 (earlier version) v2.6 (earlier version) v2.4 (earlier version) Unsupported versions
  • 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
        • Rust
    • Explore
      • SQL features
        • SQL Feature Support
        • PostgreSQL Compatibility
        • Foreign Data Wrappers
        • Schemas and Tables
        • Data Types
        • Data Manipulation
        • Queries and Joins
        • Expressions and Operators
        • Stored Procedures
        • Triggers
        • Advanced features
          • Cursors
          • Table Partitioning
          • Views
          • Savepoints
          • Collations
        • Going beyond SQL
          • Follower reads
          • Tablespaces
        • PostgreSQL extensions
      • Fault tolerance
      • Horizontal scalability
        • Scaling Transactions
        • Sharding Data
      • Transactions
        • Distributed Transactions
        • Isolation Levels
        • Explicit Locking
      • Indexes and Constraints
        • Primary keys
        • Foreign keys
        • Secondary indexes
        • Unique indexes
        • Partial indexes
        • Expression indexes
        • Covering indexes
        • GIN indexes
        • 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
      • Change data capture (CDC)
        • Debezium connector
        • Java CDC console
      • Security
      • Observability
        • Prometheus Integration
        • Grafana Dashboard
    • Drivers and ORMs
      • Java
        • JDBC drivers
        • Hibernate ORM
        • Supported versions
      • Go
        • Go drivers
        • Go ORMs
        • Supported versions
      • C#
        • C# drivers
        • C# ORMs
        • Supported versions
      • NodeJS
        • NodeJS drivers
        • NodeJS ORMs
        • Supported Versions
      • Python
        • Python drivers
        • Python ORMs
        • Supported versions
      • Rust
        • Diesel ORM
    • 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 users
        • Configure client authentication
      • 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
        • 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
      • Backup and restore
        • Export and import data
        • Distributed snapshots
        • Point-in-time recovery
      • 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
        • Recover YB-TServer from crash loop
      • 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
      • Documentation
        • Docs checklist
        • Docs layout
        • Build the docs
          • Editor setup
        • Edit the docs
          • Docs page structure
          • Syntax diagrams
        • Style guide
  • YUGABYTEDB ANYWHERE
    • Overview
      • Install
      • Configure
    • Install
      • Prerequisites
      • Prepare the environment
      • Install software
      • Prepare nodes
      • Uninstall software
    • Configure
      • Create admin user
      • Configure cloud providers
      • Configure 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
      • Eliminate an unresponsive node
      • Recover a node
      • Enable high availability
      • Edit configuration flags
      • Edit a universe
      • Delete a universe
      • Configure instance tags
      • Upgrade YugabyteDB
      • Migrate to Helm 3
    • Back up universes
      • Configure backup storage
      • Back up universe data
      • Restore universe data
      • Schedule data backups
    • Security
      • Security checklist
      • Configure ports
      • LDAP authentication
      • Authorization
      • Create a KMS configuration
      • Enable encryption at rest
      • Enable encryption in transit
      • Network security
    • Alerts and monitoring
      • Alerts
      • Live Queries dashboard
      • Slow Queries dashboard
    • Troubleshoot
      • Install and upgrade issues
      • Universe issues
    • Administer
      • Back up YugabyteDB Anywhere
      • Authenticate with LDAP
    • Upgrade
      • Upgrade Kubernetes installation
      • Upgrade using Replicated
  • YUGABYTEDB MANAGED
    • Overview
    • Quick start
      • Create a free cluster
      • Connect to the cluster
      • 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
        • VPCs
        • Peering connections
        • Create a VPC Network
    • Secure clusters
      • IP allow lists
      • Database authorization
      • Add database users
      • Encryption in transit
      • Audit account 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
      • Scale and configure clusters
      • Backup and restore
      • Maintenance windows
      • Create extensions
    • Administration and billing
      • Manage account access
      • 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
    • YugabyteDB Managed FAQ
    • What's new
  • INTEGRATIONS
    • Apache Kafka
    • Apache Spark
    • Debezium
    • Django REST framework
    • Entity Framework
    • Flyway
    • GORM
    • Hasura
      • Application Development
      • Benchmarking
    • JanusGraph
    • KairosDB
    • Liquibase
    • Metabase
    • Presto
    • Prisma
    • Sequelize
    • Spring Framework
      • Spring Data YugabyteDB
      • Spring Data JPA
      • Spring Data Cassandra
    • SQLAlchemy
    • WSO2 Identity Server
    • YSQL Loader
    • YugabyteDB JDBC driver
  • 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 FOREIGN DATA WRAPPER
            • ALTER FOREIGN TABLE
            • ALTER GROUP
            • ALTER POLICY
            • ALTER ROLE
            • ALTER SEQUENCE
            • ALTER SERVER
            • ALTER TABLE
            • ALTER USER
            • ANALYZE
            • BEGIN
            • CALL
            • COMMENT
            • COMMIT
            • COPY
            • CREATE AGGREGATE
            • CREATE CAST
            • CREATE DATABASE
            • CREATE DOMAIN
            • CREATE EXTENSION
            • CREATE FOREIGN DATA WRAPPER
            • CREATE FOREIGN TABLE
            • 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 SERVER
            • CREATE TABLE
            • CREATE TABLE AS
            • CREATE TRIGGER
            • CREATE TYPE
            • CREATE USER
            • CREATE USER MAPPING
            • CREATE VIEW
            • DEALLOCATE
            • DELETE
            • DO
            • DROP AGGREGATE
            • DROP CAST
            • DROP DATABASE
            • DROP DOMAIN
            • DROP EXTENSION
            • DROP FOREIGN DATA WRAPPER
            • DROP FOREIGN TABLE
            • 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 SERVER
            • DROP TABLE
            • DROP TRIGGER
            • DROP TYPE
            • DROP USER
            • END
            • EXECUTE
            • EXPLAIN
            • GRANT
            • IMPORT FOREIGN SCHEMA
            • 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()
          • setval()
          • 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()
        • 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 and ORMs
      • JDBC Drivers
      • C# Drivers
      • Go Drivers
      • Python Drivers
      • Client drivers for YSQL
      • Client drivers for YCQL
    • Connectors
      • Kafka Connect YugabyteDB
    • Third party tools
      • pgAdmin
      • Apache Superset
      • Arctype
      • DBeaver
      • TablePlus
      • DbSchema
      • SQL Workbench/J
      • Cassandra Workbench
    • Sample datasets
      • Chinook
      • Northwind
      • PgExercises
      • SportsDB
      • Retail Analytics
  • RELEASES
    • Releases overview
      • v2.13 series (preview)
      • 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
    • YugabyteDB Anywhere 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 > Four ways to specify offset > Name-resolution rules >

Rule 4

Report a doc issue Suggest new content Contributor guide
  • Test with a string that's found uniquely in 'pg_timezone_names.name'
  • Test with a string that's found both in 'pg_timezone_names.name' and in 'pg_timezone_abbrevs.abbrev'
  • Who wins?
  • Can the test be carried out during the winter?

A string that's intended to identify a UTC offset is resolved first in pg_timezone_abbrevs.abbrev and, only if this fails, then in pg_timezone_names.name.

This applies only in those syntax contexts where pg_timezone_abbrevs.abbrev is a candidate for the resolution—so not for set timezone, which looks only in pg_timezone_names.name.


Download and install the date-time utilities code.

The code on this page depends on the code presented in the extended_timezone_names view section. This is included in the larger code kit that includes all of the reusable code that the overall date-time section describes and uses.

The page for Rule 3 tested with a string that's found uniquely in pg_timezone_abbrevs.abbrev. It established that for the second two syntax contexts (the at time zone operator and the text literal for a timestamptz value), the string is looked up in this column; and that for the first syntax context (the set timezone statement) this column is not searched.

Test with a string that's found uniquely in 'pg_timezone_names.name'

You can discover, with ad hoc queries. that the string Europe/Amsterdam occurs only in pg_timezone_names.name. Use the function occurrences() to confirm it thus

with c as (select occurrences('Europe/Amsterdam') as r)
select
  (c.r).names_name     ::text as "~names.name",
  (c.r).names_abbrev   ::text as "~names.abbrev",
  (c.r).abbrevs_abbrev ::text as "~abbrevs.abbrev"
from c;

This is the result:

 ~names.name | ~names.abbrev | ~abbrevs.abbrev
-------------+---------------+-----------------
 true        | false         | false

This means that the string Europe/Amsterdam can be used as a probe, using the function legal_scopes_for_syntax_context()_:

select x from legal_scopes_for_syntax_context('Europe/Amsterdam');

This is the result:

 Europe/Amsterdam:   names_name: true / names_abbrev: false / abbrevs_abbrev: false
 ------------------------------------------------------------------------------------------
 set timezone = 'Europe/Amsterdam';                           > OK
 select timezone('Europe/Amsterdam', '2021-06-07 12:00:00');  > OK
 select '2021-06-07 12:00:00 Europe/Amsterdam'::timestamptz;  > OK

So pg_timezone_names.name is searched in each of the three syntax contexts.

Test with a string that's found both in 'pg_timezone_names.name' and in 'pg_timezone_abbrevs.abbrev'

The outcomes of the test that substantiated Rule-3 and of the test above raise the question of priority: what if the string that's intended to specify the UTC offset occurs in both columns?

You can discover, with ad hoc queries. that the string MET occurs both in pg_timezone_names.name and in pg_timezone_abbrevs.abbrev. Use the function occurrences() to confirm it thus

with c as (select occurrences('MET') as r)
select
  (c.r).names_name     ::text as "~names.name",
  (c.r).names_abbrev   ::text as "~names.abbrev",
  (c.r).abbrevs_abbrev ::text as "~abbrevs.abbrev"
from c;

This is the result:

 ~names.name | ~names.abbrev | ~abbrevs.abbrev
-------------+---------------+-----------------
 true        | false         | true

This means that the string MET can be used as a probe, using the function legal_scopes_for_syntax_context()_:

select x from legal_scopes_for_syntax_context('MET');

Predictably, this is the result:

 MET:                names_name: true / names_abbrev: false / abbrevs_abbrev: true
 ------------------------------------------------------------------------------------------
 set timezone = 'MET';                                        > OK
 select timezone('MET', '2021-06-07 12:00:00');               > OK
 select '2021-06-07 12:00:00 MET'::timestamptz;               > OK

Who wins?

The PostgresSQL documentation does not provide the answer. But the question can be answered empirically if MET (or another such string that occurs in both columns) maps to different UTC_offset values in the two different columns. Try this:

with
  met_names_offsets(string, names_offset, is_dst) as (
    select name, utc_offset, is_dst
    from pg_timezone_names
    where name = 'MET'),

  met_abbrevs_offset(string, abbrevs_offset) as (
    select abbrev, utc_offset
    from pg_timezone_abbrevs
    where abbrev = 'MET'),

possibly_disagreeing_offsets(string, names_offset, is_dst, abbrevs_offset) as (
  select string, n.names_offset, n.is_dst, a.abbrevs_offset
  from
    met_names_offsets as n
    inner join
    met_abbrevs_offset as a
    using(string))

select string, names_offset, is_dst::text, abbrevs_offset
from possibly_disagreeing_offsets;

This is the result:

 string | names_offset | is_dst | abbrevs_offset
--------+--------------+--------+----------------
 MET    | 02:00:00     | true   | 01:00:00

Of course, there is just one row because both pg_timezone_names.name and pg_timezone_abbrevs.abbrev have unique values. You can see that the query happens to have been executed during the Day Light Savings Time period for the timezone MET. This is fortunate for the usefulness of the test that follows. Look up MET in the extended_timezone_names view.

select name, std_abbrev, dst_abbrev, std_offset, dst_offset
from extended_timezone_names
where name = 'MET';

This is the result:

 name | std_abbrev | dst_abbrev | std_offset | dst_offset
------+------------+------------+------------+------------
 MET  | MET        | MEST       | 01:00:00   | 02:00:00

So the test that follows would not be useful during MET's winter.

Can the test be carried out during the winter?

It turns out that no string exists that has the properties needed to do the test in the winter:

  • The string occurs both in pg_timezone_names.name and pg_timezone_abbrevs.abbrev.
  • pg_timezone_names.utc_offset and pg_timezone_abbrevs.utc_offset, for that string, differ during the winter.

You can see that with this query:

with
  ambiguous_strings(string) as (
    select name from pg_timezone_names
    intersect
    select abbrev from pg_timezone_abbrevs),

  possibly_disagreeing_offsets(
    string,
    std_abbrev,
    dst_abbrev,
    std_offset,
    dst_offset,
    abbrevs_offset)
  as (
    select
      e.name,
      e.std_abbrev,
      e.dst_abbrev,
      e.std_offset,
      e.dst_offset,
      (
        select utc_offset
        from pg_timezone_abbrevs a1
        where a1.abbrev = e.name
      )
    from extended_timezone_names e
    where e.name in (
      select a2.string from ambiguous_strings a2))

select
  string,
  std_abbrev,
  dst_abbrev,
  lpad(std_offset     ::text, 9) as "std offset from ~names",
  lpad(dst_offset     ::text, 9) as "dst offset from ~names",
  lpad(abbrevs_offset ::text, 9) as "offset from ~abbrevs"
from possibly_disagreeing_offsets
order by string;

This is the result:

 string | std_abbrev | dst_abbrev | std offset from ~names | dst offset from ~names | offset from ~abbrevs
--------+------------+------------+------------------------+------------------------+----------------------
 CET    | CET        | CEST       |  01:00:00              |  02:00:00              |  01:00:00
 EET    | EET        | EEST       |  02:00:00              |  03:00:00              |  02:00:00

 EST    | EST        | EST        | -05:00:00              | -05:00:00              | -05:00:00
 GMT    | GMT        | GMT        |  00:00:00              |  00:00:00              |  00:00:00
 HST    | HST        | HST        | -10:00:00              | -10:00:00              | -10:00:00

 MET    | MET        | MEST       |  01:00:00              |  02:00:00              |  01:00:00

 MST    | MST        | MST        | -07:00:00              | -07:00:00              | -07:00:00
 UCT    | UCT        | UCT        |  00:00:00              |  00:00:00              |  00:00:00
 UTC    | UTC        | UTC        |  00:00:00              |  00:00:00              |  00:00:00

 WET    | WET        | WEST       |  00:00:00              |  01:00:00              |  00:00:00

The blank lines were added by hand to highlight the rows where the value of "offset from ~abbrevs" differs from one of "std offset from ~names" or "dst offset from ~names". Notice that when it does differ, it always differs from the summer value. This means that the test cannot be carried out in the winter.

The names with the summer difference are CET, EET, MET, and WET.

Try the following exhaustive demonstration of the priority rule. (Of course, the demonstration will work only in the summer!) The test design rests on the rule that was established for the case that the string that specifies the UTC offset specifies the same value in both the ::timestamptz and the at time zone syntax contexts here in the section "Sensitivity of converting between timestamptz and plain timestamp to the UTC offset".

But, here, there is a critical difference in how the rule is formulated. It's formulated here to cover the conventional a priori assumption that's made at the application design stage when choosing between the two alternative ways to convert a plain timestamp value to a timestamptz value, thus:

  IF:
    ts_with_tz_1 ◄— ts_plain::timestamptz # Following « set timezone = 'the_string' »
  AND:
    ts_with_tz_2 ◄— ts_plain at time zone 'the_string'
  THEN:
    ts_with_tz_2 == ts_with_tz_1

Execute the test for a set of two kinds of string, as the comments in the initialization code of the strings text[] array explain. Notice that the if test means that the value of string is output only when the timestamptz values produced by the two different syntaxes disagree. And for each such output, it shows the difference (as an interval value, of course) between the two disagreeing timestamptz values

drop function if exists priority_rule_demo() cascade;

create function priority_rule_demo()
  returns table(z text)
  language plpgsql
as $body$
declare
  set_timezone  constant text      not null := $$set timezone = '%s'$$;
  tz_on_entry   constant text      not null := current_setting('timezone');
  t0            constant timestamp not null := '2021-06-20 12:00:00'::timestamp;
  the_string             text      not null := '';
  strings       constant text[]    not null := array
                                                    [
                  /* These offset strings occur */    'Pacific/Pago_Pago',
                  /* uniquely in "~names.name"  */    'America/Porto_Velho',
                                                      'Atlantic/South_Georgia',
                                                      'Africa/Tripoli',
                                                      'Asia/Dubai',
                                                      'Pacific/Kiritimati',

                  /* These offset strings occur */    'CET',
                  /* both in "~names.name"      */    'EET',
                  /* and in "~abbrevs.abbrev"   */    'MET',
                                                      'WET'
                                                      ];
begin
  z := rpad('Timezone', 25)||lpad('t0::timestamptz - t0 at time zone "the_string"', 49);   return next;
  z := rpad('-', 25, '-')  ||lpad('----------------------------------------------', 49);   return next;
  foreach the_string in array strings loop
  execute format(set_timezone, the_string);
    declare
      t1    constant timestamptz      not null := t0::timestamptz;
      e1    constant double precision not null := extract(epoch from t1);

      t2    constant timestamptz      not null := t0 at time zone the_string;
      e2    constant double precision not null := extract(epoch from t2);

      diff  constant interval         not null := make_interval(secs=>(e2 - e1));
    begin
      if e1 <> e2 then
        z :=
          rpad(the_string, 25)||
          lpad(to_char(diff, 'hh24:mi')::text, 49);                                        return next;
      end if;
    end;
  end loop;

execute format(set_timezone, tz_on_entry);
end;
$body$;

select z from priority_rule_demo();

This is the result:

 Timezone                    t0::timestamptz - t0 at time zone "the_string"
 -------------------------   ----------------------------------------------
 CET                                                                  01:00
 EET                                                                  01:00
 MET                                                                  01:00
 WET                                                                  01:00

Notice that the difference, when it's non-zero, is always equal to the difference between the UTC offset values read from the "~names.name" column and the "~abbrevs.abbrev" column— one hour in each case.

This outcome supports the formulation of the rule that this page addresses.

The results also highlight an insidious risk. Suppose that a developer doesn't know the priority rule and assumes (erroneously, but arguably reasonably) that a timezone name never occurs in pg_timezone_abbrevs.abbrev (or, maybe, that if it did then pg_timezone_names.name would win). And assume that she carries out acceptance tests of her application code, using any of the four timezone names where the ~names offset and the ~abbrevs offset differ only in the summer—and that she does this testing in the winter. All will seem to be good. And then the summer will bring silent wrong results!

Yugabyte recommends that you program your application code defensively so that you explicitly avoid this risk by ensuring that names that are used to specify the UTC offset occur only in pg_timezone_names.name. The section Recommended practice for specifying the UTC offset explains how to do this.

  • Test with a string that's found uniquely in 'pg_timezone_names.name'
  • Test with a string that's found both in 'pg_timezone_names.name' and in 'pg_timezone_abbrevs.abbrev'
  • Who wins?
  • Can the test be carried out during the winter?
Ask our community
  • Slack
  • Github
  • Forum
  • StackOverflow
Yugabyte
Contact Us
Copyright © 2017-2022 Yugabyte, Inc. All rights reserved.