From 1813b982415dfbe2c0792f77ebb5abe2d4207ccc Mon Sep 17 00:00:00 2001 From: Wojciech Barcik <wbarcik@syncad.com> Date: Tue, 29 Sep 2020 19:43:12 +0200 Subject: [PATCH] Setup database monitoring with pghero --- .gitignore | 5 ++ scripts/db-monitoring/.env_example | 1 + scripts/db-monitoring/docker-compose.yml | 17 +++- scripts/db-monitoring/pghero_example.yml | 7 ++ scripts/db-monitoring/readme-monitoring.md | 85 ++++++++++++------- .../setup/create_database_pghero.sql | 9 ++ .../setup/create_role_pghero.sql | 21 +++++ .../setup/create_role_pgwatch2.sql | 22 +++++ .../setup/create_tables_pghero.sql | 38 +++++++++ .../create_template.sql} | 2 +- .../db-monitoring/setup/pghero_cron_jobs.txt | 13 +++ .../setup/postgresql_monitoring.conf | 45 ++++++++++ .../db-monitoring/setup/setup_monitoring.sh | 72 ++++++++++++++++ .../setup/setup_monitoring_pghero.sql | 68 +++++++++++++++ .../setup_monitoring_pgwatch2.sql} | 8 +- .../{ => setup}/setup_template.sql | 0 16 files changed, 375 insertions(+), 38 deletions(-) create mode 100644 scripts/db-monitoring/.env_example create mode 100644 scripts/db-monitoring/pghero_example.yml create mode 100644 scripts/db-monitoring/setup/create_database_pghero.sql create mode 100644 scripts/db-monitoring/setup/create_role_pghero.sql create mode 100644 scripts/db-monitoring/setup/create_role_pgwatch2.sql create mode 100644 scripts/db-monitoring/setup/create_tables_pghero.sql rename scripts/db-monitoring/{create_database.sql => setup/create_template.sql} (71%) create mode 100644 scripts/db-monitoring/setup/pghero_cron_jobs.txt create mode 100644 scripts/db-monitoring/setup/postgresql_monitoring.conf create mode 100755 scripts/db-monitoring/setup/setup_monitoring.sh create mode 100644 scripts/db-monitoring/setup/setup_monitoring_pghero.sql rename scripts/db-monitoring/{setup_monitoring.sql => setup/setup_monitoring_pgwatch2.sql} (97%) rename scripts/db-monitoring/{ => setup}/setup_template.sql (100%) diff --git a/.gitignore b/.gitignore index abf22f6dc..a9f31ca02 100644 --- a/.gitignore +++ b/.gitignore @@ -136,3 +136,8 @@ hive/version.py # hivemind.port hivemind.port + +Pipfile.lock + +pghero.yml +*~ diff --git a/scripts/db-monitoring/.env_example b/scripts/db-monitoring/.env_example new file mode 100644 index 000000000..e4872e06c --- /dev/null +++ b/scripts/db-monitoring/.env_example @@ -0,0 +1 @@ +PGHERO_DATABASE_URL=postgres://pghero:pghero@dev-66:5432/pghero diff --git a/scripts/db-monitoring/docker-compose.yml b/scripts/db-monitoring/docker-compose.yml index b74d1d394..5ba3fe762 100644 --- a/scripts/db-monitoring/docker-compose.yml +++ b/scripts/db-monitoring/docker-compose.yml @@ -8,17 +8,28 @@ services: ports: - "30000:3000" # Grafana dashboarding - "8080:8080" # Management Web UI (monitored hosts, metrics, metrics configurations) - - "8081:8081" # Gatherer healthcheck / statistics on number of gathered metrics (JSON) - - "54320:5432" # Postgres configuration (or metrics storage DB, when using the cybertec/pgwatch2-postgres image) + # - "8081:8081" # Gatherer healthcheck / statistics on number of gathered metrics (JSON) + # - "54320:5432" # Postgres configuration (or metrics storage DB, when using the cybertec/pgwatch2-postgres image) # - "8086:8086" # InfluxDB API (when using the InfluxDB version) # - "8088:8088" # InfluxDB Backup port (when using the InfluxDB version) - restart: always + restart: unless-stopped volumes: - pgwatch2-postgresql:/var/lib/postgresql - pgwatch2-grafana:/var/lib/grafana - pgwatch2-influxdb:/var/lib/influxdb - pgwatch2-pgwatch2:/pgwatch2/persistent-config + pghero: + # Docs: https://github.com/ankane/pghero + image: ankane/pghero:v2.7.2 + environment: + DATABASE_URL: ${PGHERO_DATABASE_URL} + restart: unless-stopped + ports: + - "8085:8080" + volumes: + - ./pghero.yml:/app/config/pghero.yml + volumes: pgwatch2-postgresql: pgwatch2-grafana: diff --git a/scripts/db-monitoring/pghero_example.yml b/scripts/db-monitoring/pghero_example.yml new file mode 100644 index 000000000..cd973a48c --- /dev/null +++ b/scripts/db-monitoring/pghero_example.yml @@ -0,0 +1,7 @@ +databases: + pghero: + url: postgres://pghero:pghero@dev-66:5432/pghero + hive_test: + url: postgres://pghero:pghero@dev-66:5432/hive_test + bamboo: + url: postgres://pghero:pghero@dev-66:5432/bamboo diff --git a/scripts/db-monitoring/readme-monitoring.md b/scripts/db-monitoring/readme-monitoring.md index 207624ac3..e578dc3c2 100644 --- a/scripts/db-monitoring/readme-monitoring.md +++ b/scripts/db-monitoring/readme-monitoring.md @@ -1,50 +1,71 @@ # Postgresql monitoring -Tutorial for Postgres version 10. +Tutorial for Postgres version 10 on Ubuntu 18.04, assuming default +configuration. We'll setup monitoring with +[pgwatch2](https://github.com/cybertec-postgresql/pgwatch2) +and [pghero](https://github.com/ankane/pghero). If you don't need these +both tools, modify this tutorial accordingly. -1. Install [pgwatch2](https://github.com/cybertec-postgresql/pgwatch2) -in docker container by running `docker-compose up -d` in directory -`scripts/db-monitoring`. We are going to setup monitoring by -unprivileged user `pgwatch2`, added to standard postgresql role -`pg_monitor`. +1. Install required apt packages: +``` +sudo apt-get install postgresql-contrib postgresql-plpython3 python3-psutil postgresql-10-pg-qualstats +``` +Note: you should install official Postgresql ubuntu +[pgdg](https://www.postgresql.org/about/news/pgdg-apt-repository-for-debianubuntu-1432/) repository to get apt package postgresql-10-pg-qualstats. -2. Install required apt packages: +2. Install postgresql custom configuration file: ``` -sudo apt-get install postgresql-contrib postgresql-plpython3 python3-psutil +sudo cp scripts/db-monitoring/setup/postgresql_monitoring.conf /etc/postgresql/10/main/conf.d/90-monitoring.conf ``` +Restart postgresql. + +3. Create roles `pgwatch2` and `pghero` (these are unprivileged roles +for monitoring) in postgresql and create template database +`template_hive_ci`, in all postgresql instances, that you want to monitor +(we need postgres superuser here): -3. Set in `postgresql.conf`: ``` -track_functions = pl -track_io_timing = on -shared_preload_libraries = 'pg_stat_statements' -track_activity_query_size = 2048 -pg_stat_statements.max = 10000 -pg_stat_statements.track = all +cd scripts/db-monitoring/setup +PSQL_OPTIONS="-p 5432 -U postgres -h 127.0.0.1" ./setup_monitoring.sh ``` -Then restart postgresql. -4. Create role `pgwatch` in postgresql: +Note that above script creates also database `pghero` for gathering historical +stats data. + +Remember, that all databases under monitoring should replicate the structure +and objects from template `template_hive_ci`, so you should create them with +command: ``` -CREATE ROLE pgwatch2 WITH LOGIN PASSWORD 'pgwatch2'; --- NB! For critical databases it might make sense to ensure that the user account --- used for monitoring can only open a limited number of connections --- (there are according checks in code, but multiple instances might be launched) -ALTER ROLE pgwatch2 CONNECTION LIMIT 10; -GRANT pg_monitor TO pgwatch2; +create database some_db template template_hive_ci ``` -5. Create template database `template_hive_ci` -(you'll need db superuser privileges): +In case of already existing database, which you can't recreate, you should +install needed stuff into it by running command: ``` -psql -p 5432 -U postgres -h 127.0.0.1 -f ./create_database.sql --set=db_name=template_hive_ci -psql -p 5432 -U postgres -h 127.0.0.1 -d template_hive_ci -f ./setup_monitoring.sql -psql -p 5432 -U postgres -h 127.0.0.1 -f ./setup_template.sql --set=db_name=template_hive_ci +cd scripts/db-monitoring/setup +PSQL_OPTIONS="-p 5432 -U postgres -h 127.0.0.1" ./setup_monitoring.sh some_existing_db_name yes yes no no ``` -6. Enter databases to be monitored by pgwatch2 +4. Create `.env` file and create configuration file for `pghero` +(edit to your needs): +``` +cp scripts/db-monitoring/docker/.env_example scripts/db-monitoring/.env +cp scripts/db-monitoring/docker/pghero_example.yml scripts/db-monitoring/docker/pghero.yml +``` + +5. Run services `pgwatch2` and `pghero` in docker containers: +``` +cd scripts/db-monitoring +docker-compose up -d +``` + +7. Enter databases to be monitored by `pgwatch2` at http://ci-server.domain:8080. It's recommended to setup -[postgres-continuous-discovery](https://pgwatch2.readthedocs.io/en/latest/preparing_databases.html#different-db-types-explained). Use unprivileged -user `pgwatch2` created earlier. +[postgres-continuous-discovery](https://pgwatch2.readthedocs.io/en/latest/preparing_databases.html#different-db-types-explained). +Use unprivileged user `pgwatch2` created earlier. + +8. Go to http://ci-server.domain:30000/ to see dashboard produced by +`pgwatch2`. -7. Go to http://ci-server.domain:30000/ to see stats. +9. Go to http://ci-server.domain:8085/ to see dashboard produced by +`pghero`. diff --git a/scripts/db-monitoring/setup/create_database_pghero.sql b/scripts/db-monitoring/setup/create_database_pghero.sql new file mode 100644 index 000000000..69cd26f47 --- /dev/null +++ b/scripts/db-monitoring/setup/create_database_pghero.sql @@ -0,0 +1,9 @@ +-- Create database + +-- Example run: +-- psql -p 5432 -U postgres -h 127.0.0.1 -f ./create_database_pghero.sql + +SET client_encoding = 'UTF8'; +SET client_min_messages = 'warning'; + +CREATE DATABASE pghero OWNER pghero; diff --git a/scripts/db-monitoring/setup/create_role_pghero.sql b/scripts/db-monitoring/setup/create_role_pghero.sql new file mode 100644 index 000000000..56cc17bbc --- /dev/null +++ b/scripts/db-monitoring/setup/create_role_pghero.sql @@ -0,0 +1,21 @@ +-- Create database + +-- Example run: +-- psql -p 5432 -U postgres -h 127.0.0.1 -f ./create_role_pghero.sql + +SET client_encoding = 'UTF8'; +SET client_min_messages = 'warning'; + +DO +$do$ +BEGIN + IF EXISTS (SELECT * FROM pg_user WHERE pg_user.usename = 'pghero') THEN + raise warning 'Role % already exists', 'pghero'; + ELSE + CREATE ROLE pghero WITH LOGIN PASSWORD 'pghero'; + ALTER ROLE pghero CONNECTION LIMIT 10; + ALTER ROLE pghero SET search_path = pghero, pg_catalog, public; + GRANT pg_monitor TO pghero; + END IF; +END +$do$ diff --git a/scripts/db-monitoring/setup/create_role_pgwatch2.sql b/scripts/db-monitoring/setup/create_role_pgwatch2.sql new file mode 100644 index 000000000..e64ccd27a --- /dev/null +++ b/scripts/db-monitoring/setup/create_role_pgwatch2.sql @@ -0,0 +1,22 @@ +-- Create database + +-- Example run: +-- psql -p 5432 -U postgres -h 127.0.0.1 -f ./create_role_pgwatch2.sql + +SET client_encoding = 'UTF8'; +SET client_min_messages = 'warning'; + +DO +$do$ +BEGIN + IF EXISTS (SELECT * FROM pg_user WHERE pg_user.usename = 'pgwatch2') THEN + raise warning 'Role % already exists', 'pgwatch2'; + ELSE + -- NB! For critical databases it might make sense to ensure that the user account + -- used for monitoring can only open a limited number of connections + -- (there are according checks in code, but multiple instances might be launched) + ALTER ROLE pgwatch2 CONNECTION LIMIT 10; + GRANT pg_monitor TO pgwatch2; + END IF; +END +$do$ diff --git a/scripts/db-monitoring/setup/create_tables_pghero.sql b/scripts/db-monitoring/setup/create_tables_pghero.sql new file mode 100644 index 000000000..7d85d32e8 --- /dev/null +++ b/scripts/db-monitoring/setup/create_tables_pghero.sql @@ -0,0 +1,38 @@ +-- Create database + +-- Creates tables for gathering historical stats data. You need them in pghero +-- database only. +-- Example run: +-- psql postgresql://pghero:pghero@127.0.0.1:5432/pghero -f ./create_tables_pghero.sql + +SET client_encoding = 'UTF8'; +SET client_min_messages = 'warning'; + + +BEGIN; + +CREATE SCHEMA pghero; + +CREATE TABLE "pghero_query_stats" ( + "id" bigserial primary key, + "database" text, + "user" text, + "query" text, + "query_hash" bigint, + "total_time" float, + "calls" bigint, + "captured_at" timestamp +); +CREATE INDEX ON "pghero_query_stats" ("database", "captured_at"); + +CREATE TABLE "pghero_space_stats" ( + "id" bigserial primary key, + "database" text, + "schema" text, + "relation" text, + "size" bigint, + "captured_at" timestamp +); +CREATE INDEX ON "pghero_space_stats" ("database", "captured_at"); + +COMMIT; diff --git a/scripts/db-monitoring/create_database.sql b/scripts/db-monitoring/setup/create_template.sql similarity index 71% rename from scripts/db-monitoring/create_database.sql rename to scripts/db-monitoring/setup/create_template.sql index 040977f84..7e4e0409c 100644 --- a/scripts/db-monitoring/create_database.sql +++ b/scripts/db-monitoring/setup/create_template.sql @@ -1,7 +1,7 @@ -- Create database -- Example run: --- psql -p 5432 -U postgres -h 127.0.0.1 -f ./create_database.sql --set=db_name=template_hive_ci +-- psql -p 5432 -U postgres -h 127.0.0.1 -f ./create_template.sql --set=db_name=template_hive_ci SET client_encoding = 'UTF8'; SET client_min_messages = 'warning'; diff --git a/scripts/db-monitoring/setup/pghero_cron_jobs.txt b/scripts/db-monitoring/setup/pghero_cron_jobs.txt new file mode 100644 index 000000000..5a2092418 --- /dev/null +++ b/scripts/db-monitoring/setup/pghero_cron_jobs.txt @@ -0,0 +1,13 @@ +# Install with `crontab -e` + +# Pghero gather query stats +*/5 * * * * docker exec -e DATABASE_URL=postgres://pghero:pghero@hive-4.pl.syncad.com:5432/pghero dbmonitoring_pghero_1 bin/rake pghero:capture_query_stats > /dev/null 2>&1 + +# Pghero gather space stats +*/5 * * * * docker exec -e DATABASE_URL=postgres://pghero:pghero@hive-4.pl.syncad.com:5432/pghero dbmonitoring_pghero_1 bin/rake pghero:capture_space_stats > /dev/null 2>&1 + +# Pghero remove query stats +@monthly docker exec -e DATABASE_URL=postgres://pghero:pghero@hive-4.pl.syncad.com:5432/pghero dbmonitoring_pghero_1 bin/rake pghero:clean_query_stats > /dev/null 2>&1 + +set-option -s set-clipboard off +bind-key -T copy-mode-vi MouseDragEnd1Pane send-keys -X copy-pipe-and-cancel "xclip -se c -i" diff --git a/scripts/db-monitoring/setup/postgresql_monitoring.conf b/scripts/db-monitoring/setup/postgresql_monitoring.conf new file mode 100644 index 000000000..9989bd4bb --- /dev/null +++ b/scripts/db-monitoring/setup/postgresql_monitoring.conf @@ -0,0 +1,45 @@ +# Custom postgresql conf file for monitoring. +# Put it into e.g. `/etc/postgresql/10/main/conf.d/90-monitoring.conf` + +shared_preload_libraries = 'pg_stat_statements,pg_qualstats' + +## pg_stat_statements +## See https://www.postgresql.org/docs/10/pgstatstatements.html + +track_functions = pl +track_io_timing = on +track_activity_query_size = 2048 + +pg_stat_statements.max = 10000 +pg_stat_statements.track = all + + +## pg_qualstats +## See https://github.com/powa-team/pg_qualstats +## See https://powa.readthedocs.io/en/latest/components/stats_extensions/pg_qualstats.html + +# pg_qualstats.enabled (boolean, default true): whether or not pg_qualstats +# should be enabled + +# pg_qualstats.track_constants (bolean, default true): whether or not +# pg_qualstats should keep track of each constant value individually. +# Disabling this GUC will considerably reduce the number of entries +# necessary to keep track of predicates. + +# pg_qualstats.max: the maximum number of predicated and query text tracked +# (defaults to 1000) + +# pg_qualstats.resolve_oids (boolean, default false): whether or not +# pg_qualstats should resolve oids at query time, or juste store the oids. +# Enabling this parameter makes the data analysis much more easy, since +# a connection to the database where the query was executed won't be necessary, +# but it will eat much more space (624 bytes per entry instead of 176). +# Additionnaly, this will require some catalog lookups, which aren't free. + +# pg_qualstats.track_pg_catalog (boolean, default false): whether or not +# pg_qualstats should compute predicates on object in pg_catalog schema. + +# pg_qualstats.sample_rate (double, default -1): the fraction of queries that +# should be sampled. For example, 0.1 means that only one out of ten queries +# will be sampled. The default (-1) means automatic, and results in a value +# of 1 / max_connections, so that statiscally, concurrency issues will be rare. diff --git a/scripts/db-monitoring/setup/setup_monitoring.sh b/scripts/db-monitoring/setup/setup_monitoring.sh new file mode 100755 index 000000000..819b18d51 --- /dev/null +++ b/scripts/db-monitoring/setup/setup_monitoring.sh @@ -0,0 +1,72 @@ +#!/bin/bash + +# Create stuff for monitoring. + +DB_NAME=${1:-template_hive_ci} +SETUP_MONITORING_PGWATCH2=${2:-yes} +SETUP_MONITORING_PGHERO=${3:-yes} +CREATE_TEMPLATE=${4:-yes} +CREATE_DB_PGHERO=${5:-yes} + +if [ -z "$PSQL_OPTIONS" ]; then + PSQL_OPTIONS="-p 5432 -U postgres -h 127.0.0.1" +fi + +setup_monitoring_pgwatch2() { + # Install stuff for pgwatch2 into database under monitoring. + psql $PSQL_OPTIONS -f ./create_role_pgwatch2.sql + psql $PSQL_OPTIONS -d $DB_NAME -f ./setup_monitoring_pgwatch2.sql +} + +setup_monitoring_pghero() { + # Install stuff for pghero into database under monitoring + psql $PSQL_OPTIONS -f ./create_role_pghero.sql + psql $PSQL_OPTIONS -d $DB_NAME -f ./setup_monitoring_pghero.sql +} + +create_db_pghero() { + # Create database for pghero for collecting historical stats data. + psql $PSQL_OPTIONS -f ./create_database_pghero.sql + psql postgresql://pghero:pghero@127.0.0.1:5432/pghero -f ./create_tables_pghero.sql +} + +create_template() { + # Create template database. + echo "Creating template database $DB_NAME" + psql $PSQL_OPTIONS -f ./create_template.sql --set=db_name=$DB_NAME +} + +lock_template() { + # Lock connections to template database. + echo "Locking connections to template database $DB_NAME" + psql $PSQL_OPTIONS -f ./setup_template.sql --set=db_name=$DB_NAME +} + +main() { + + # Run flow. + + if [ "$CREATE_TEMPLATE" = "yes" ]; then + create_template + fi + + if [ "$SETUP_MONITORING_PGWATCH2" = "yes" ]; then + setup_monitoring_pgwatch2 + fi + + if [ "$SETUP_MONITORING_PGHERO" = "yes" ]; then + setup_monitoring_pghero + fi + + if [ "$CREATE_DB_PGHERO" = "yes" ]; then + create_db_pghero + fi + + if [ "$CREATE_TEMPLATE" = "yes" ]; then + lock_template + fi + +} + +# main +echo "$PSQL_OPTIONS" diff --git a/scripts/db-monitoring/setup/setup_monitoring_pghero.sql b/scripts/db-monitoring/setup/setup_monitoring_pghero.sql new file mode 100644 index 000000000..21a18d34f --- /dev/null +++ b/scripts/db-monitoring/setup/setup_monitoring_pghero.sql @@ -0,0 +1,68 @@ +-- Configure database for monitoring by unprivileged user `pgwatch2` +-- using program https://github.com/cybertec-postgresql/pgwatch2/ + +-- Example run: +-- psql -p 5432 -U postgres -h 127.0.0.1 -d template_hive_ci -f ./setup_monitoring.sql + +SET client_encoding = 'UTF8'; +SET client_min_messages = 'warning'; + + +BEGIN; + +CREATE SCHEMA IF NOT EXISTS pghero; + +CREATE EXTENSION IF NOT EXISTS pg_stat_statements WITH SCHEMA public; +COMMENT ON EXTENSION pg_stat_statements + IS 'Track execution statistics of all SQL statements executed'; + +-- view queries +CREATE OR REPLACE FUNCTION pghero.pg_stat_activity() RETURNS SETOF pg_stat_activity AS +$$ + SELECT * FROM pg_catalog.pg_stat_activity; +$$ LANGUAGE sql VOLATILE SECURITY DEFINER; + +CREATE VIEW pghero.pg_stat_activity AS SELECT * FROM pghero.pg_stat_activity(); + +-- kill queries +CREATE OR REPLACE FUNCTION pghero.pg_terminate_backend(pid int) RETURNS boolean AS +$$ + SELECT * FROM pg_catalog.pg_terminate_backend(pid); +$$ LANGUAGE sql VOLATILE SECURITY DEFINER; + +-- query stats +CREATE OR REPLACE FUNCTION pghero.pg_stat_statements() RETURNS SETOF pg_stat_statements AS +$$ + SELECT * FROM public.pg_stat_statements; +$$ LANGUAGE sql VOLATILE SECURITY DEFINER; + +CREATE VIEW pghero.pg_stat_statements AS SELECT * FROM pghero.pg_stat_statements(); + +-- query stats reset +CREATE OR REPLACE FUNCTION pghero.pg_stat_statements_reset() RETURNS void AS +$$ + SELECT public.pg_stat_statements_reset(); +$$ LANGUAGE sql VOLATILE SECURITY DEFINER; + +-- improved query stats reset for Postgres 12+ - delete for earlier versions +-- CREATE OR REPLACE FUNCTION pghero.pg_stat_statements_reset(userid oid, dbid oid, queryid bigint) RETURNS void AS +-- $$ +-- SELECT public.pg_stat_statements_reset(userid, dbid, queryid); +-- $$ LANGUAGE sql VOLATILE SECURITY DEFINER; + +-- suggested indexes +CREATE OR REPLACE FUNCTION pghero.pg_stats() RETURNS +TABLE(schemaname name, tablename name, attname name, null_frac real, avg_width integer, n_distinct real) AS +$$ + SELECT schemaname, tablename, attname, null_frac, avg_width, n_distinct FROM pg_catalog.pg_stats; +$$ LANGUAGE sql VOLATILE SECURITY DEFINER; + +CREATE VIEW pghero.pg_stats AS SELECT * FROM pghero.pg_stats(); + +GRANT USAGE ON SCHEMA pghero TO pg_monitor; + +GRANT SELECT ON ALL TABLES IN SCHEMA pghero TO pg_monitor; + +GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA pghero TO pg_monitor; + +COMMIT; diff --git a/scripts/db-monitoring/setup_monitoring.sql b/scripts/db-monitoring/setup/setup_monitoring_pgwatch2.sql similarity index 97% rename from scripts/db-monitoring/setup_monitoring.sql rename to scripts/db-monitoring/setup/setup_monitoring_pgwatch2.sql index e9f9fbd57..5754e72b7 100644 --- a/scripts/db-monitoring/setup_monitoring.sql +++ b/scripts/db-monitoring/setup/setup_monitoring_pgwatch2.sql @@ -2,16 +2,17 @@ -- using program https://github.com/cybertec-postgresql/pgwatch2/ -- Example run: --- psql -p 5432 -U postgres -h 127.0.0.1 -d template_hive_ci -f ./setup_monitoring.sql +-- psql -p 5432 -U postgres -h 127.0.0.1 -d template_hive_ci -f ./setup_monitoring_pgwatch2.sql SET client_encoding = 'UTF8'; SET client_min_messages = 'warning'; +-- TODO We need extension pg_qualstats, see https://www.cybertec-postgresql.com/en/pgwatch2-v1-7-0-released/ BEGIN; -CREATE SCHEMA pgwatch2; +CREATE SCHEMA IF NOT EXISTS pgwatch2; CREATE EXTENSION IF NOT EXISTS plpython3u WITH SCHEMA pg_catalog; COMMENT ON EXTENSION plpython3u IS 'PL/Python3U untrusted procedural language'; @@ -20,6 +21,9 @@ CREATE EXTENSION IF NOT EXISTS pg_stat_statements WITH SCHEMA public; COMMENT ON EXTENSION pg_stat_statements IS 'Track execution statistics of all SQL statements executed'; +CREATE EXTENSION IF NOT EXISTS pg_qualstats; +COMMENT ON EXTENSION pg_qualstats + IS 'Statistics on predicates found in WHERE statements and JOIN clauses.'; CREATE FUNCTION pgwatch2.get_load_average(OUT load_1min double precision, OUT load_5min double precision, OUT load_15min double precision) diff --git a/scripts/db-monitoring/setup_template.sql b/scripts/db-monitoring/setup/setup_template.sql similarity index 100% rename from scripts/db-monitoring/setup_template.sql rename to scripts/db-monitoring/setup/setup_template.sql -- GitLab