PostgreSQL Tutorial

  • Home
  • Stored Procedures
  • Triggers
  • Views
  • Interfaces
    • PostgreSQL PHP
    • PostgreSQL Python
    • PostgreSQL JDBC
  • Functions
Home / PostgreSQL Tutorial / Understanding PostgreSQL Timestamp Data Types

Understanding PostgreSQL Timestamp Data Types

Summary: in this tutorial, we will introduce you to the PostgreSQL timestamp data types including timestamp and timestamptz, and show you how to use some handy functions to handle timestamp data more effectively.

Introduction to PostgreSQL timestamp

PostgreSQL TimestampPostgreSQL provides two temporal data types for handling timestamp, one without timezone ( timestamp) and one with timezone ( timestamptz).

The timestamp data type allows you to store both date and time. However, it does not have any time zone data. It means that when you change your database server’s time zone, the timestamp value stored in the database does not change.

The timestamptz data is the timestamp with time zone. The timestamptz is a time zone-aware date and time data type. PostgreSQL stores the timestamptz in UTC value. When you insert a value into a timestamptz column, PostgreSQL converts the timestamptz value into a UTC value and stores the UTC value in the table.

When you query timestamptz from the database, PostgreSQL converts the UTC value back to the time value of the timezone set by the database server, the user, or the current database connection.

Notice that both timestamp and timestamptz uses 8 bytes for storing the timestamp value as shown in the following query:

1
2
3
4
5
6
7
SELECT
      typname,
      typlen
FROM
      pg_type
WHERE
      typname ~ '^timestamp';

1
2
3
4
5
   typname   | typlen
-------------+--------
timestamp   |      8
timestamptz |      8
(2 rows)

It’s important to note that timestamptz value is stored as a UTC value. PostgreSQL does not store any timezone data with the timestamptz value.

PostgreSQL timestamp example

Let’s take a look at an example of using the timestamp and timestamptz to have a better understanding of how the PostgresQL handles them.

First, create a table that consists of both timestamp the timestamptz columns.

1
CREATE TABLE timestamp_demo (ts TIMESTAMP, tstz TIMESTAMPTZ);

Next, set the time zone of the database server to  America/Los_Angeles.

1
SET timezone = 'America/Los_Angeles';

By the way, you can see the current time zone using the SHOW TIMEZONE command:

1
SHOW TIMEZONE;

1
2
3
4
      TimeZone
---------------------
America/Los_Angeles
(1 row)

Then, insert a new row into the timstamp_demo table:

1
2
3
4
5
6
INSERT INTO timestamp_demo (ts, tstz)
VALUES
(
'2016-06-22 19:10:25-07',
'2016-06-22 19:10:25-07'
);

After that, query data from the timestamp and timestamptz columns.

1
2
3
4
SELECT
ts
FROM
timestampz_demo;

1
2
3
4
         ts          |          tstz
---------------------+------------------------
2016-06-22 19:10:25 | 2016-06-22 19:10:25-07
(1 row)

It returns the same values as we inserted.

Finally, change the timezone of the current session to America/New_York and query data again.

1
SET timezone = 'America/New_York';

1
2
3
4
5
SELECT
ts,
tstz
FROM
timestamp_demo;

1
2
3
4
         ts          |          tstz
---------------------+------------------------
2016-06-22 19:10:25 | 2016-06-22 22:10:25-04
(1 row)

The value in the timestamp column does not change, whereas the value in the timestamptz column is adjusted to the new time zone of 'America/New_York'.

It is a generally best practice to use the timestamptz data type to store the timestamp data.

PostgreSQL timestamp functions

To handle timestamp data effectively, PostgreSQL provides some handy functions as follows:

Getting the current time

To get the current timestamp you use the NOW() function as follows:

1
SELECT NOW();

1
2
3
4
              now
-------------------------------
2016-06-22 20:44:52.134125-07
(1 row)

Or you can use the CURRENT_TIMESTAMP:

1
SELECT CURRENT_TIMESTAMP;

To get the current time without date, you use CURRENT_TIME:

1
2
3
4
       timetz
--------------------
20:49:04.566025-07
(1 row)

Note that both CURRENT_TIMESTAMP and CURRENT_TIME return the current time with time zone.

To get the time of day in the string format, you use the timeofday() function.

1
SELECT TIMEOFDAY();

1
2
3
              timeofday
-------------------------------------
Wed Jun 22 20:51:12.632420 2016 PDT

Convert between timezones

To convert a timestamp to another time zone, you use the timezone(zone, timestamp) function.

1
SHOW TIMEZONE;

1
2
3
4
      TimeZone
---------------------
America/Los_Angeles
(1 row)

The current timezone is America/Los_Angeles.

To convert 2016-06-01 00:00 to America/New_York timezone, you use the timezone() function as follows:

1
SELECT timezone('America/New_York','2016-06-01 00:00');

1
2
3
4
      timezone
---------------------
2016-06-01 03:00:00
(1 row)

Note that we pass the timestamp as a string to the timezone() function, PostgreSQL casts it to timestamptz implicitly. It is better to cast a timestamp value to the timestamptz data type explicitly as the following statement:

1
SELECT timezone('America/New_York','2016-06-01 00:00'::timestamptz);

In this tutorial, we have introduced you to the PostgreSQL timestamp data type and shown you how to use some useful functions for manipulating timestamp values.

Related Tutorials

  • PostgreSQL Data Types
Previous Tutorial: The Ultimate Guide to PostgreSQL Date By Examples
Next Tutorial: A Comprehensive Look at PostgreSQL Interval Data Type

PostgreSQL Quick Start

  • What is PostgreSQL?
  • Install PostgreSQL
  • Connect to Database
  • Download PostgreSQL Sample Database
  • Load Sample Database
  • Explore Server and Database Objects

PostgreSQL Fundamentals

  • PostgreSQL Select
  • PostgreSQL Order By
  • PostgreSQL Select Distinct
  • PostgreSQL Where
  • PostgreSQL LIMIT
  • PostgreSQL IN
  • PostgreSQL Between
  • PostgreSQL Like
  • PostgreSQL Inner Join
  • PostgreSQL Left Join
  • PostgreSQL Full Outer Join
  • PostgreSQL Cross Join
  • PostgreSQL Natural Join
  • PostgreSQL Group By
  • PostgreSQL Having
  • PostgreSQL Union
  • PostgreSQL Intersect
  • PostgreSQL Except
  • PostgreSQL Subquery
  • PostgreSQL Insert
  • PostgreSQL Update
  • PostgreSQL Delete
  • PostgreSQL Data Types
  • PostgreSQL Create Table
  • PostgreSQL Alter Table
  • PostgreSQL Drop Table
  • PostgreSQL Truncate Table
  • PostgreSQL CHECK Constraint
  • PostgreSQL Not-Null Constraint
  • PostgreSQL Foreign Key
  • PostgreSQL Primary Key
  • PostgreSQL UNIQUE Constraint

About PostgreSQL Tutorial

PostgreSQLTutorial.com is a website dedicated to developers and database administrators who are working on PostgreSQL database management system.

We constantly publish useful PostgreSQL tutorials to keep you up-to-date with the latest PostgreSQL features and technologies. All PostgreSQL tutorials are simple, easy-to-follow and practical.

Recent PostgreSQL Tutorials

  • How To Change The Password of a PostgreSQL User
  • PostgreSQL AGE Function
  • PostgreSQL DATE_PART Function
  • PostgreSQL List Users
  • PostgreSQL NOW Function
  • PostgreSQL DATE_TRUNC Function
  • PostgreSQL TO_DATE Function: Convert String to Date
  • A Look at PostgreSQL User-defined Data Types
  • PostgreSQL Copy Database Made Easy
  • How to Get Table, Database, Indexes, Tablespace, and Value Size in PostgreSQL

More Tutorials

  • PostgreSQL Cheat Sheet
  • PostgreSQL Administration
  • PostgreSQL PHP
  • PostgreSQL Python
  • PostgreSQL JDBC
  • PostgreSQL Resources

Site Info

  • Home
  • About Us
  • Contact Us
  • Privacy Policy

Copyright © 2017 by PostgreSQL Tutorial Website. All Rights Reserved.