From 41bdfb4406d2f8fb5ae9ff863309c16768930ccd Mon Sep 17 00:00:00 2001 From: Michael Gaffney Date: Wed, 31 May 2023 15:19:42 -0400 Subject: [PATCH] fix(db): Fix time zone consistency issues in monthly billing views The hcp monthly billing views build a range of buckets using the `generate_series` and the `now()` functions along with relative offsets like `+ 1 month`. The calculated start and end times for these views can vary depending on the time zone setting of the PostgreSQL server. This adds 3 table functions that call their respective views with the time zone set to UTC. Calling these functions instead of their underlying views directly prevents the returned values from varying when the server's time zone is not set to UTC. This also drops support for PostgreSQL 11. The included tests use the `date_trunc(field, source [, time_zone ])` function added in PostgreSQL 12. Fixes: 41b1b5b4b74b38141ddf934ff274dfb5c5b53d0e --- .github/workflows/test-sql.yml | 2 +- CHANGELOG.md | 2 + CONTRIBUTING.md | 2 +- README.md | 2 +- .../postgres/70/03_hcp_billing_monthly.up.sql | 48 ++++++++ internal/db/sqltest/README.md | 2 +- .../tests/hcp/billing/monthly_timezone.sql | 116 ++++++++++++++++++ internal/oplog/testing.go | 4 +- testing/dbtest/docker/Dockerfile.11-alpine | 7 -- testing/dbtest/docker/Makefile | 2 +- 10 files changed, 173 insertions(+), 14 deletions(-) create mode 100644 internal/db/sqltest/tests/hcp/billing/monthly_timezone.sql delete mode 100644 testing/dbtest/docker/Dockerfile.11-alpine diff --git a/.github/workflows/test-sql.yml b/.github/workflows/test-sql.yml index 252ccfdf85..8defd9cf27 100644 --- a/.github/workflows/test-sql.yml +++ b/.github/workflows/test-sql.yml @@ -13,7 +13,7 @@ jobs: runs-on: ${{ fromJSON(vars.RUNNER) }} strategy: matrix: - postgres-version: [ latest, 11-alpine, 12-alpine, 13-alpine, 14-alpine, 15-alpine ] + postgres-version: [ latest, 12-alpine, 13-alpine, 14-alpine, 15-alpine ] name: SQL Tests ${{ matrix.postgres-version }} steps: - uses: actions/checkout@8e5e7e5ab8b370d6c329ec480221332ada57f0ab # v3.5.2 diff --git a/CHANGELOG.md b/CHANGELOG.md index 40ce23594e..28bbf3bc9a 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -40,6 +40,8 @@ Canonical reference for changes, improvements, and bugfixes for Boundary. [PR2](https://github.com/hashicorp/boundary-plugin-aws/pull/24), [PR3](https://github.com/hashicorp/boundary-plugin-azure/pull/12), [PR4](https://github.com/hashicorp/boundary/pull/3266)). +* PostgreSQL 12 or greater is now required. PostgreSQL 11 is no longer + supported. ### New and Improved diff --git a/CONTRIBUTING.md b/CONTRIBUTING.md index afe0db78e3..8a44ee1ca5 100644 --- a/CONTRIBUTING.md +++ b/CONTRIBUTING.md @@ -153,7 +153,7 @@ $ make test-database-up $ docker logs custom-name ``` -The default docker image is built using the `postgres:11` base image. +The default docker image is built using the `postgres:12` base image. The image can be changed using a make option to test against other versions: ``` diff --git a/README.md b/README.md index 908c34c3a5..018e89ecc0 100644 --- a/README.md +++ b/README.md @@ -52,7 +52,7 @@ on-premises technologies as well. * The database contains Boundary's configuration and session information and must be accessible by Controller nodes. Values that are secrets (such as credentials) are encrypted in the database. Currently, PostgreSQL is supported - as a database and has been tested with Postgres 11 and above. Boundary uses + as a database and has been tested with Postgres 12 and above. Boundary uses only common extensions and both hosted and self-run instances are supported. In most instances all that is needed is a database endpoint and appropriate credentials. diff --git a/internal/db/schema/migrations/oss/postgres/70/03_hcp_billing_monthly.up.sql b/internal/db/schema/migrations/oss/postgres/70/03_hcp_billing_monthly.up.sql index 6ddab358cd..a3c8dab710 100644 --- a/internal/db/schema/migrations/oss/postgres/70/03_hcp_billing_monthly.up.sql +++ b/internal/db/schema/migrations/oss/postgres/70/03_hcp_billing_monthly.up.sql @@ -41,4 +41,52 @@ begin; 'The current month is a sum from the beginning of the current month ' 'until the start of the current hour (exclusive).'; + create function hcp_billing_monthly_sessions_current_month() + returns table(start_time timestamp with time zone, end_time timestamp with time zone, sessions_pending_count bigint) + as $$ + select * from hcp_billing_monthly_sessions_current_month; + $$ language sql + immutable + parallel safe -- all of the functions called are parallel safe + strict -- means the function returns null on null input + set timezone to 'utc'; + comment on function hcp_billing_monthly_sessions_current_month is + 'hcp_billing_monthly_sessions_current_month is a function that contains ' + 'the sum of pending sessions ' + 'from the beginning of the current month ' + 'until the start of the current hour (exclusive). ' + 'All timestamps returned are in UTC.'; + + create function hcp_billing_monthly_sessions_last_2_months() + returns table(start_time timestamp with time zone, end_time timestamp with time zone, sessions_pending_count bigint) + as $$ + select * from hcp_billing_monthly_sessions_last_2_months; + $$ language sql + immutable + parallel safe -- all of the functions called are parallel safe + strict -- means the function returns null on null input + set timezone to 'utc'; + comment on function hcp_billing_monthly_sessions_last_2_months is + 'hcp_billing_monthly_sessions_last_2_months is a function that contains ' + 'the sum of pending sessions for the current month and the previous month. ' + 'The current month is a sum from the beginning of the current month ' + 'until the start of the current hour (exclusive). ' + 'All timestamps returned are in UTC.'; + + create function hcp_billing_monthly_sessions_all() + returns table(start_time timestamp with time zone, end_time timestamp with time zone, sessions_pending_count bigint) + as $$ + select * from hcp_billing_monthly_sessions_all; + $$ language sql + immutable + parallel safe -- all of the functions called are parallel safe + strict -- means the function returns null on null input + set timezone to 'utc'; + comment on function hcp_billing_monthly_sessions_all is + 'hcp_billing_monthly_sessions_all is a function that contains ' + 'the sum of pending sessions for the current month and all previous months. ' + 'The current month is a sum from the beginning of the current month ' + 'until the start of the current hour (exclusive). ' + 'All timestamps returned are in UTC.'; + commit; diff --git a/internal/db/sqltest/README.md b/internal/db/sqltest/README.md index 07d4fe3268..a934508267 100644 --- a/internal/db/sqltest/README.md +++ b/internal/db/sqltest/README.md @@ -76,7 +76,7 @@ Different versions of postgres can easily be tested: ```bash make PG_DOCKER_TAG=latest +make PG_DOCKER_TAG=14-alpine make PG_DOCKER_TAG=13-alpine make PG_DOCKER_TAG=12-alpine -make PG_DOCKER_TAG=11-alpine ``` diff --git a/internal/db/sqltest/tests/hcp/billing/monthly_timezone.sql b/internal/db/sqltest/tests/hcp/billing/monthly_timezone.sql new file mode 100644 index 0000000000..d398145978 --- /dev/null +++ b/internal/db/sqltest/tests/hcp/billing/monthly_timezone.sql @@ -0,0 +1,116 @@ +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: MPL-2.0 + +begin; + select plan(20); + + select lives_ok('truncate wh_session_connection_accumulating_fact, wh_session_accumulating_fact', + 'Truncate tables in preparation for testing'); + + -- validate the warehouse fact tables are empty + select is(count(*), 0::bigint, 'wh_session_connection_accumulating_fact is not empty') from wh_session_connection_accumulating_fact; + select is(count(*), 0::bigint, 'wh_session_accumulating_fact is not empty' ) from wh_session_accumulating_fact; + + -- validate the view returns no rows + select is(count(*), 0::bigint, 'hcp_billing_monthly_sessions_all should return 0 rows when there are no sessions') from hcp_billing_monthly_sessions_all; + select is(count(*), 1::bigint, 'hcp_billing_monthly_sessions_current_month should return 1 rows when there are no sessions') from hcp_billing_monthly_sessions_current_month; + select results_eq('select sessions_pending_count from hcp_billing_monthly_sessions_current_month', + array[0::bigint], + 'hcp_billing_monthly_sessions_current_month should return 1 row with 0 sessions pending'); + select is(count(*), 2::bigint, 'hcp_billing_monthly_sessions_last_2_months should return 2 rows when there are no sessions') from hcp_billing_monthly_sessions_last_2_months; + select results_eq('select sessions_pending_count from hcp_billing_monthly_sessions_last_2_months', + array[0::bigint, 0::bigint], + 'hcp_billing_monthly_sessions_last_2_months should return 2 rows each with 0 sessions pending'); + + + set time zone 'NZ'; + + with time_series (time) as ( + select date_trunc('month', now(), 'utc') - interval '1 minute' + ), + dim_keys (host_key, user_key, credential_group_key) as ( + select h.key, u.key, 'no credentials' + from (select key from wh_host_dimension limit 1) as h, + (select key from wh_user_dimension limit 1) as u + ), + dim_time_series (date_key, time_key, time) as ( + select wh_date_key(time), wh_time_key(time), time + from time_series + ), + fake_sessions (session_id, auth_token_id, + host_key, user_key, credential_group_key, + session_pending_date_key, session_pending_time_key, session_pending_time) as ( + select concat('s__________', t.date_key, t.time_key), concat('a__________', t.date_key, t.time_key), + k.host_key, k.user_key, k.credential_group_key, + t.date_key, t.time_key,t.time + from dim_keys as k, + dim_time_series as t + ) + insert into wh_session_accumulating_fact + (session_id, auth_token_id, + host_key, user_key, credential_group_key, + session_pending_date_key, session_pending_time_key, session_pending_time + ) + select session_id, auth_token_id, + host_key, user_key, credential_group_key, + session_pending_date_key, session_pending_time_key, session_pending_time + from fake_sessions; + + create table test_counts_all ( + start_time timestamptz primary key, + end_time timestamptz, + sessions_pending_count bigint not null default 0 + ); + create table test_counts_current_month as select * from test_counts_all; + + insert into test_counts_all + (start_time, end_time, sessions_pending_count) + select date_trunc('month', now(), 'utc') as start_time, -- this month + date_trunc('hour', now(), 'utc') as end_time, + 0::bigint + union + select date_trunc('month', now() - interval '1 month', 'utc') as start_time, -- last month + date_trunc('month', now(), 'utc') as end_time, + 1::bigint; + + create table test_counts_last_2_months as select * from test_counts_all; + + insert into test_counts_current_month + (start_time, end_time, sessions_pending_count) + select date_trunc('month', now(), 'utc') as start_time, -- this month + date_trunc('hour', now(), 'utc') as end_time, + 0::bigint; + + -- all + prepare select_func_hcp_billing_monthly_sessions_all as select * from hcp_billing_monthly_sessions_all(); + prepare select_view_hcp_billing_monthly_sessions_all as select * from hcp_billing_monthly_sessions_all; + prepare select_test_counts_all as select * from test_counts_all order by start_time desc; + + select results_eq('select_test_counts_all', 'select_func_hcp_billing_monthly_sessions_all', 'set time zone before insert: results_eq'); + select results_ne('select_test_counts_all', 'select_view_hcp_billing_monthly_sessions_all', 'set time zone before insert: results_ne'); + select set_eq('select_test_counts_all', 'select_func_hcp_billing_monthly_sessions_all', 'set time zone before insert: set_eq'); + select set_ne('select_test_counts_all', 'select_view_hcp_billing_monthly_sessions_all', 'set time zone before insert: set_ne'); + + -- current month + prepare select_func_hcp_billing_monthly_sessions_current_month as select * from hcp_billing_monthly_sessions_current_month(); + prepare select_view_hcp_billing_monthly_sessions_current_month as select * from hcp_billing_monthly_sessions_current_month; + prepare select_test_counts_current_month as select * from test_counts_current_month order by start_time desc; + + select results_eq('select_test_counts_current_month', 'select_func_hcp_billing_monthly_sessions_current_month', 'set time zone before insert: results_eq'); + select results_ne('select_test_counts_current_month', 'select_view_hcp_billing_monthly_sessions_current_month', 'set time zone before insert: results_ne'); + select set_eq('select_test_counts_current_month', 'select_func_hcp_billing_monthly_sessions_current_month', 'set time zone before insert: set_eq'); + select set_ne('select_test_counts_current_month', 'select_view_hcp_billing_monthly_sessions_current_month', 'set time zone before insert: set_ne'); + + -- last 2 months + prepare select_func_hcp_billing_monthly_sessions_last_2_months as select * from hcp_billing_monthly_sessions_last_2_months(); + prepare select_view_hcp_billing_monthly_sessions_last_2_months as select * from hcp_billing_monthly_sessions_last_2_months; + prepare select_test_counts_last_2_months as select * from test_counts_last_2_months order by start_time desc; + + select results_eq('select_test_counts_last_2_months', 'select_func_hcp_billing_monthly_sessions_last_2_months', 'set time zone before insert: results_eq'); + select results_ne('select_test_counts_last_2_months', 'select_view_hcp_billing_monthly_sessions_last_2_months', 'set time zone before insert: results_ne'); + select set_eq('select_test_counts_last_2_months', 'select_func_hcp_billing_monthly_sessions_last_2_months', 'set time zone before insert: set_eq'); + select set_ne('select_test_counts_last_2_months', 'select_view_hcp_billing_monthly_sessions_last_2_months', 'set time zone before insert: set_ne'); + + select * from finish(); + +rollback; diff --git a/internal/oplog/testing.go b/internal/oplog/testing.go index 0f831e4d6a..f92857ebc8 100644 --- a/internal/oplog/testing.go +++ b/internal/oplog/testing.go @@ -143,13 +143,13 @@ func testListConstraints(t testing.TB, db *dbw.DB, tableName string) []constrain ccu.table_schema as table_schema, ccu.table_name, ccu.column_name, - pgc.consrc as definition + pg_get_constraintdef(pgc.oid) as definition from pg_constraint pgc join pg_namespace nsp on nsp.oid = pgc.connamespace join pg_class cls on pgc.conrelid = cls.oid left join information_schema.constraint_column_usage ccu on pgc.conname = ccu.constraint_name - and nsp.nspname = ccu.constraint_schema + and nsp.nspname = ccu.constraint_schema -- where contype ='c' where ccu.table_name = ? order by ccu.table_name,pgc.conname ` diff --git a/testing/dbtest/docker/Dockerfile.11-alpine b/testing/dbtest/docker/Dockerfile.11-alpine deleted file mode 100644 index bb1098f7a8..0000000000 --- a/testing/dbtest/docker/Dockerfile.11-alpine +++ /dev/null @@ -1,7 +0,0 @@ -FROM postgres:11-alpine - -ADD init-db.sh /docker-entrypoint-initdb.d/00-init-db.sh -ADD restore-benchmark-dumps.sh /docker-entrypoint-initdb.d/01-restore-benchmark-dumps.sh -ADD postgresql.conf /etc/postgresql/postgresql.conf - -CMD ["postgres", "-c", "config_file=/etc/postgresql/postgresql.conf"] diff --git a/testing/dbtest/docker/Makefile b/testing/dbtest/docker/Makefile index eb4ee98ff2..4b5a3aed10 100644 --- a/testing/dbtest/docker/Makefile +++ b/testing/dbtest/docker/Makefile @@ -6,7 +6,7 @@ DOCKER_ARGS ?= -d DOCKER_MIRROR?=docker.io REGISTRY_NAME?=hashicorpboundary TEST_IMAGE_NAME=postgres -TEST_IMAGE_TAG ?= $(DOCKER_MIRROR)/$(REGISTRY_NAME)/$(TEST_IMAGE_NAME):11-alpine +TEST_IMAGE_TAG ?= $(DOCKER_MIRROR)/$(REGISTRY_NAME)/$(TEST_IMAGE_NAME):12-alpine PG_OPTS ?= TEST_DB_PORT ?= 5432 TEST_CONTAINER_NAME ?= boundary-sql-tests