diff --git a/.circleci/config.yml b/.circleci/config.yml deleted file mode 100644 index b55ccb3..0000000 --- a/.circleci/config.yml +++ /dev/null @@ -1,77 +0,0 @@ -version: 2 - -workflows: - version: 2 - test: - jobs: - - test-10 - - test-11 - - test-12 - - test-13 - - test-14 - -jobs: - test-10: &test-template - working_directory: ~/postgres_dba - docker: - - image: postgres:10 - environment: - - POSTGRES_VERSION: 10 - steps: - - run: - name: Install Git - command: apt update && apt install -y git - - checkout - - run: - name: Init Postgres cluster - command: | - pg_createcluster $POSTGRES_VERSION main - echo 'local all all trust' > /etc/postgresql/$POSTGRES_VERSION/main/pg_hba.conf - echo "shared_preload_libraries='pg_stat_statements'" >> /etc/postgresql/$POSTGRES_VERSION/main/postgresql.conf - pg_ctlcluster $POSTGRES_VERSION main start - - run: - name: Prepare DB - command: | - psql -U postgres -c 'create database test' - psql -U postgres test -c 'create extension pg_stat_statements' - psql -U postgres test -c 'create extension pgstattuple' - psql -U postgres test -c "create table align1 as select 1::int4, 2::int8, 3::int4 as more from generate_series(1, 100000) _(i);" - psql -U postgres test -c "create table align2 as select 1::int4, 3::int4 as more, 2::int8 from generate_series(1, 100000) _(i);" - - run: - name: Tests - command: | - echo "\set postgres_dba_wide true" > ~/.psqlrc - echo "\set postgres_dba_interactive_mode false" >> ~/.psqlrc - for f in ~/postgres_dba/sql/*; do psql -U postgres test -f ~/postgres_dba/warmup.psql -f "$f">/dev/null; done - echo "\set postgres_dba_wide false" > ~/.psqlrc - echo "\set postgres_dba_interactive_mode false" >> ~/.psqlrc - for f in ~/postgres_dba/sql/*; do psql -U postgres test -f ~/postgres_dba/warmup.psql -f "$f">/dev/null; done - diff -b test/regression/0_node.out <(psql -U postgres test -f warmup.psql -f ~/postgres_dba/sql/0_node.sql | grep Role) - diff -b test/regression/p1_alignment_padding.out <(psql -U postgres test -f warmup.psql -f ~/postgres_dba/sql/p1_alignment_padding.sql | grep align) - diff -b test/regression/a1_activity.out <(psql -U postgres test -f warmup.psql -f ~/postgres_dba/sql/a1_activity.sql | grep User) - test-11: - <<: *test-template - docker: - - image: postgres:11 - environment: - - POSTGRES_VERSION: 11 - test-12: - <<: *test-template - docker: - - image: postgres:12 - environment: - - POSTGRES_VERSION: 12 - - test-13: - <<: *test-template - docker: - - image: postgres:13 - environment: - - POSTGRES_VERSION: 13 - - test-14: - <<: *test-template - docker: - - image: postgres:14 - environment: - - POSTGRES_VERSION: 14 diff --git a/.github/workflows/test.yml b/.github/workflows/test.yml new file mode 100644 index 0000000..0ac7c29 --- /dev/null +++ b/.github/workflows/test.yml @@ -0,0 +1,149 @@ +name: Test PostgreSQL Versions + +on: + push: + branches: [ master, main ] + pull_request: + branches: [ master, main ] + +jobs: + test: + runs-on: ubuntu-latest + + strategy: + matrix: + postgres-version: ['13', '14', '15', '16', '17', '18'] + fail-fast: false + + services: + postgres: + image: postgres:${{ matrix.postgres-version }} + env: + POSTGRES_PASSWORD: postgres + POSTGRES_DB: test + POSTGRES_HOST_AUTH_METHOD: trust + POSTGRES_INITDB_ARGS: --auth-host=trust --auth-local=trust + options: >- + --health-cmd pg_isready + --health-interval 10s + --health-timeout 5s + --health-retries 5 + ports: + - 5432:5432 + + steps: + - name: Checkout code + uses: actions/checkout@v4 + + - name: Install PostgreSQL client + run: | + # Install default PostgreSQL client (works for all versions) + sudo apt-get update + sudo apt-get install -y postgresql-client + + # Verify installation + psql --version + + - name: Prepare test database + run: | + # Wait for PostgreSQL to be ready + until pg_isready -h localhost -p 5432 -U postgres; do + echo "Waiting for postgres..." + sleep 2 + done + + # Check PostgreSQL version + psql -h localhost -U postgres -d test -c 'SELECT version();' + + # Create extensions (pg_stat_statements may not work without shared_preload_libraries) + psql -h localhost -U postgres -d test -c 'CREATE EXTENSION IF NOT EXISTS pg_stat_statements;' || echo "Warning: pg_stat_statements extension not available" + psql -h localhost -U postgres -d test -c 'CREATE EXTENSION IF NOT EXISTS pgstattuple;' + + # Create minimal privilege user for testing + psql -h localhost -U postgres -d test -c "CREATE USER dba_user;" + psql -h localhost -U postgres -d test -c "GRANT pg_monitor TO dba_user;" + psql -h localhost -U postgres -d test -c "GRANT CONNECT ON DATABASE test TO dba_user;" + psql -h localhost -U postgres -d test -c "GRANT USAGE ON SCHEMA public TO dba_user;" + + # Verify extensions + psql -h localhost -U postgres -d test -c 'SELECT extname FROM pg_extension ORDER BY extname;' + + # Create test tables for alignment testing (as superuser) + psql -h localhost -U postgres -d test -c "CREATE TABLE align1 AS SELECT 1::int4, 2::int8, 3::int4 AS more FROM generate_series(1, 100000) _(i);" + psql -h localhost -U postgres -d test -c "CREATE TABLE align2 AS SELECT 1::int4, 3::int4 AS more, 2::int8 FROM generate_series(1, 100000) _(i);" + + # Grant access to test tables for dba_user + psql -h localhost -U postgres -d test -c "GRANT SELECT ON ALL TABLES IN SCHEMA public TO dba_user;" + + # Test connection as dba_user + psql -h localhost -U dba_user -d test -c 'SELECT current_user, session_user;' + + - name: Test wide mode + run: | + echo "\set postgres_dba_wide true" > ~/.psqlrc + echo "\set postgres_dba_interactive_mode false" >> ~/.psqlrc + echo "Testing all SQL files in wide mode with minimal privileges..." + for f in sql/*; do + echo " Testing $f..." + if ! psql -h localhost -U dba_user -d test --no-psqlrc -f warmup.psql -f "$f" > /dev/null 2>&1; then + echo "❌ FAILED: $f in wide mode" + echo "Error output:" + psql -h localhost -U dba_user -d test --no-psqlrc -f warmup.psql -f "$f" + exit 1 + fi + done + echo "✅ All tests passed in wide mode" + + - name: Test normal mode + run: | + echo "\set postgres_dba_wide false" > ~/.psqlrc + echo "\set postgres_dba_interactive_mode false" >> ~/.psqlrc + echo "Testing all SQL files in normal mode with minimal privileges..." + for f in sql/*; do + echo " Testing $f..." + if ! psql -h localhost -U dba_user -d test --no-psqlrc -f warmup.psql -f "$f" > /dev/null 2>&1; then + echo "❌ FAILED: $f in normal mode" + echo "Error output:" + psql -h localhost -U dba_user -d test --no-psqlrc -f warmup.psql -f "$f" + exit 1 + fi + done + echo "✅ All tests passed in normal mode" + + - name: Run regression tests + run: | + echo "\set postgres_dba_wide false" > ~/.psqlrc + echo "\set postgres_dba_interactive_mode false" >> ~/.psqlrc + + echo "Running regression tests with minimal privileges..." + + echo " Testing 0_node.sql..." + OUTPUT=$(psql -h localhost -U dba_user -d test --no-psqlrc -f warmup.psql -f sql/0_node.sql | grep Role) + if [[ "$OUTPUT" == *"Master"* ]]; then + echo " ✓ Role test passed" + else + echo " ✗ Role test failed: $OUTPUT" + exit 1 + fi + + echo " Testing p1_alignment_padding.sql..." + OUTPUT=$(psql -h localhost -U dba_user -d test --no-psqlrc -f warmup.psql -f sql/p1_alignment_padding.sql | grep align) + if [[ "$OUTPUT" == *"align1"* && "$OUTPUT" == *"align2"* && "$OUTPUT" == *"int4, more, int8"* ]]; then + echo " ✓ Alignment padding test passed" + else + echo " ✗ Alignment padding test failed: $OUTPUT" + exit 1 + fi + + echo " Testing a1_activity.sql..." + OUTPUT=$(psql -h localhost -U dba_user -d test --no-psqlrc -f warmup.psql -f sql/a1_activity.sql | grep User) + if [[ "$OUTPUT" == *"User"* ]]; then + echo " ✓ Activity test passed" + else + echo " ✗ Activity test failed: $OUTPUT" + exit 1 + fi + + echo "✅ All regression tests passed with minimal privileges" + + diff --git a/README.md b/README.md index 3106b1d..c2c30c1 100644 --- a/README.md +++ b/README.md @@ -6,7 +6,7 @@ The missing set of useful tools for Postgres DBA and mere mortals. Demo -:point_right: See also [postgres-checkup](https://gitlab.com/postgres-ai/postgres-checkup), a tool for automated health checks and SQL performance analysis. +:point_right: See also [postgres_ai](https://github.com/postgres-ai/postgres_ai), a comprehensive monitoring and optimization platform that includes automated health checks, SQL performance analysis, and much more. ## Questions? @@ -34,6 +34,19 @@ sudo apt-get install -y postgresql-client-12 Using alternative psql pager called "pspg" is highly recommended (but not required): https://github.com/okbob/pspg. +## Supported PostgreSQL Versions + +**postgres_dba** is tested and supports **PostgreSQL 13-18**, including the latest PostgreSQL 18 release. + +- ✅ **PostgreSQL 13** - Fully supported +- ✅ **PostgreSQL 14** - Fully supported +- ✅ **PostgreSQL 15** - Fully supported +- ✅ **PostgreSQL 16** - Fully supported +- ✅ **PostgreSQL 17** - Fully supported (includes `pg_stat_checkpointer` compatibility) +- ✅ **PostgreSQL 18** - Fully supported (latest release) + +Older versions (9.6-12) may work but are not actively tested. Some reports may require specific PostgreSQL features introduced in newer versions. + ## Installation The installation is trivial. Clone the repository and put "dba" alias to your `.psqlrc` file (works in bash, zsh, and csh): ```bash diff --git a/sql/0_node.sql b/sql/0_node.sql index 6a19c8c..f6878ce 100644 --- a/sql/0_node.sql +++ b/sql/0_node.sql @@ -8,6 +8,7 @@ For Postgres versions older than 10, run this first: \set postgres_dba_is_wal_replay_paused pg_is_xlog_replay_paused */ + with data as ( select s.* from pg_stat_database s @@ -48,28 +49,41 @@ select 'Started At', pg_postmaster_start_time()::timestamptz(0)::text union all select 'Uptime', (now() - pg_postmaster_start_time())::interval(0)::text union all -select - 'Checkpoints', - (select (checkpoints_timed + checkpoints_req)::text from pg_stat_bgwriter) +\if :postgres_dba_pgvers_17plus +select 'Checkpoints', (select (num_timed + num_requested)::text from pg_stat_checkpointer) union all -select - 'Forced Checkpoints', - ( - select round(100.0 * checkpoints_req::numeric / - (nullif(checkpoints_timed + checkpoints_req, 0)), 1)::text || '%' - from pg_stat_bgwriter - ) +select 'Forced Checkpoints', ( + select round(100.0 * num_requested::numeric / + (nullif(num_timed + num_requested, 0)), 1)::text || '%' + from pg_stat_checkpointer +) union all -select - 'Checkpoint MB/sec', - ( - select round((nullif(buffers_checkpoint::numeric, 0) / - ((1024.0 * 1024 / - (current_setting('block_size')::numeric)) - * extract('epoch' from now() - stats_reset) - ))::numeric, 6)::text - from pg_stat_bgwriter - ) +select 'Checkpoint MiB/sec', ( + select round((nullif(buffers_written::numeric, 0) / + ((1024.0 * 1024 / + (current_setting('block_size')::numeric)) + * extract('epoch' from now() - stats_reset) + ))::numeric, 6)::text + from pg_stat_checkpointer +) +\else +select 'Checkpoints', (select (checkpoints_timed + checkpoints_req)::text from pg_stat_bgwriter) +union all +select 'Forced Checkpoints', ( + select round(100.0 * checkpoints_req::numeric / + (nullif(checkpoints_timed + checkpoints_req, 0)), 1)::text || '%' + from pg_stat_bgwriter +) +union all +select 'Checkpoint MiB/sec', ( + select round((nullif(buffers_checkpoint::numeric, 0) / + ((1024.0 * 1024 / + (current_setting('block_size')::numeric)) + * extract('epoch' from now() - stats_reset) + ))::numeric, 6)::text + from pg_stat_bgwriter +) +\endif union all select repeat('-', 33), repeat('-', 88) union all diff --git a/warmup.psql b/warmup.psql index a96cceb..a964275 100644 --- a/warmup.psql +++ b/warmup.psql @@ -4,6 +4,8 @@ select 1/0; \endif +select current_setting('server_version_num')::integer >= 170000 as postgres_dba_pgvers_17plus \gset + select current_setting('server_version_num')::integer >= 130000 as postgres_dba_pgvers_13plus \gset select current_setting('server_version_num')::integer >= 100000 as postgres_dba_pgvers_10plus \gset