Skip to content

Instantly share code, notes, and snippets.

@tiagopog
Last active August 31, 2020 15:54
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save tiagopog/30377d6607f2f0ebfa87be1e88c9878e to your computer and use it in GitHub Desktop.
Save tiagopog/30377d6607f2f0ebfa87be1e88c9878e to your computer and use it in GitHub Desktop.
Bookings – Example of how to fetch bookings stored with wall-clock times.
/*
* 1. Create a sample table to store our bookings:
*/
> CREATE TABLE bookings (id INT, scheduled_date DATE, start_time TIMESTAMP, end_time TIMESTAMP, timezone_id VARCHAR(40))
> \d bookings
-- +----------------+-----------------------------+-------------+
-- | Column | Type | Modifiers |
-- |----------------+-----------------------------+-------------|
-- | id | integer | |
-- | scheduled_date | date | |
-- | start_time | timestamp without time zone | |
-- | end_time | timestamp without time zone | |
-- +----------------+-----------------------------+-------------+
/*
* 2. Feed the just created table with some records:
*/
-- One booking for a merchant located at Los Angeles timezone:
> INSERT INTO bookings (id, scheduled_date, start_time, end_time, timezone_id) VALUES (1, '2020-09-10', '2020-09-10 11:00:00', '2020-09-10 12:00:00', 'America/Los_Angeles')
-- Another booking for a merchant located at New York timezone:
> INSERT INTO bookings (id, scheduled_date, start_time, end_time, timezone_id) VALUES (2, '2020-09-10', '2020-09-10 11:00:00', '2020-09-10 12:00:00', 'America/New_York')
> SELECT * FROM bookings
-- +------+------------------+---------------------+---------------------+---------------------+
-- | id | scheduled_date | start_time | end_time | timezone_id |
-- |------+------------------+---------------------+---------------------+---------------------|
-- | 1 | 2020-08-31 | 2020-08-31 11:00:00 | 2020-08-31 12:00:00 | America/Los_Angeles |
-- | 2 | 2020-08-31 | 2020-08-31 11:00:00 | 2020-08-31 12:00:00 | America/New_York |
-- +------+------------------+---------------------+---------------------+---------------------+
/*
* 3. Query bookings with up-to-date UTC offsets (take them from IANA's Time Zone Database):
*/
-- Example 1 – Check the UTC start time for all bookings scheduled on a given date:
> SELECT bookings.id, start_time, end_time, timezone_id, (start_time || timezones.utc_offset)::timestamptz utc_start_time
...> FROM bookings
...> INNER JOIN (VALUES ('America/New_York', '-04'), ('America/Los_Angeles', '-07')) AS timezones (id, utc_offset) ON bookings.timezone_id = timezones.id
...> WHERE scheduled_date = '2020-08-31'
-- +------+---------------------+---------------------+---------------------+------------------------+
-- | id | start_time | end_time | timezone_id | utc_start_time |
-- |------+---------------------+---------------------+---------------------+------------------------|
-- | 1 | 2020-08-31 11:00:00 | 2020-08-31 12:00:00 | America/Los_Angeles | 2020-08-31 18:00:00+00 |
-- | 2 | 2020-08-31 11:00:00 | 2020-08-31 12:00:00 | America/New_York | 2020-08-31 15:00:00+00 |
-- +------+---------------------+---------------------+---------------------+------------------------+
-- Example 2 – Check all bookings for the next 2 hours:
> SELECT bookings.id, start_time, end_time, timezone_id, (start_time || timezones.utc_offset)::timestamptz utc_start_time
...> FROM bookings
...> INNER JOIN (VALUES ('America/New_York', '-04'), ('America/Los_Angeles', '-07')) AS timezones (id, utc_offset) ON bookings.timezone_id = timezones.id
...> WHERE scheduled_date = '2020-08-31' AND (start_time || timezones.utc_offset)::timestamptz <= NOW() + INTERVAL '2 hours'
-- +------+---------------------+---------------------+------------------+------------------------+
-- | id | start_time | end_time | timezone_id | utc_start_time |
-- |------+---------------------+---------------------+------------------+------------------------|
-- | 2 | 2020-08-31 11:00:00 | 2020-08-31 12:00:00 | America/New_York | 2020-08-31 15:00:00+00 |
-- +------+---------------------+---------------------+------------------+------------------------+
-- Example 3 – Suppose we are dealing with the same timezone ID for all bookings and this ID is stored else where like at project
-- or merchant level. We can then check IANA's up-to-date UTC offset for such timezone ID and pass it at the application level when
-- building the SQL query. It should result on something like this:
> SELECT id, start_time, end_time, (start_time || '-07')::timestamptz utc_start_time
...> FROM bookings
...> WHERE scheduled_date = '2020-08-31' AND (start_time || '-07')::timestamptz <= NOW() + INTERVAL '2 hours'
-- +------+---------------------+---------------------+------------------------+
-- | id | start_time | end_time | utc_start_time |
-- |------+---------------------+---------------------+------------------------|
-- | 1 | 2020-08-31 11:00:00 | 2020-08-31 12:00:00 | 2020-08-31 18:00:00+00 |
-- | 2 | 2020-08-31 11:00:00 | 2020-08-31 12:00:00 | 2020-08-31 18:00:00+00 |
-- +------+---------------------+---------------------+------------------------+
-- NOTE: I'm using `scheduled_date` in the examples since it's a good practice for querying bookings in an efficient way.
-- In production databases make sure to have this field indexed and present in your queries since they will perform much
-- better than directly querying indexed timestamps like `start_time` and `end_time` from the sample table.
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment