(#91) Setup pghero in haf_block_log database

This commit is contained in:
Wojciech Barcik 2022-11-04 14:27:48 +01:00 committed by Bartek Wrona
parent 5eb17bd4b4
commit ce280a796a
7 changed files with 242 additions and 5 deletions

2
.gitignore vendored
View File

@ -49,3 +49,5 @@ cmake-build-*/
# For a library or package, you might want to ignore these files since the code is
# intended to run in multiple environments; otherwise, check them in:
.python-version
*.log

View File

@ -1,6 +1,6 @@
#! /bin/bash
set -euo pipefail
set -euo pipefail
SCRIPTDIR="$( cd -- "$(dirname "$0")" >/dev/null 2>&1 ; pwd -P )"
SCRIPTSDIR="$SCRIPTDIR/haf/scripts"
@ -12,7 +12,7 @@ cleanup () {
echo "Performing cleanup...."
hived_pid=$(pidof 'hived')
echo "Hived pid: $hived_pid"
jobs -l
sudo -n kill -INT $hived_pid
@ -33,7 +33,7 @@ cleanup () {
if [ "$postgres_pid" -ne 0 ];
then
tail --pid=$postgres_pid -f /dev/null || true
fi
fi
echo "postgres finish done."
@ -72,10 +72,10 @@ then
sudo -n ./haf/scripts/setup_postgres.sh --haf-admin-account=haf_admin --haf-binaries-dir="/home/haf_admin/build" --haf-database-store="$HAF_DB_STORE/tablespace"
echo "Postgres instance setup completed."
else
sudo -n mkdir -p $PGDATA
sudo -n mkdir -p $PGDATA
sudo -n mkdir -p $HAF_DB_STORE/tablespace
sudo -n chown -Rc postgres:postgres $HAF_DB_STORE
echo "Attempting to setup postgres instance..."
# Here is an exception against using /etc/init.d/postgresql script to manage postgres - maybe there is some better way to force initdb using regular script.
@ -86,6 +86,7 @@ else
echo "Postgres instance setup completed."
./haf/scripts/setup_db.sh --haf-db-admin=haf_admin --haf-db-name=haf_block_log --haf-app-user=haf_app_admin
./haf/scripts/pghero/setup_pghero.sh --database=haf_block_log
fi
cd /home/hived/datadir

View File

@ -752,6 +752,18 @@ default_text_search_config = 'pg_catalog.english'
# Add settings for extensions here
### For pghero monitoring.
shared_preload_libraries = 'pg_stat_statements'
track_functions = pl
track_io_timing = on
track_activity_query_size = 2048
# pg_stat_statements.max = 10000
pg_stat_statements.track = all
### HAF default settings
cluster_name = '12/haf_main'

48
scripts/pghero/README.md Normal file
View File

@ -0,0 +1,48 @@
### Pghero monitoring
You need to enable
[pg_stat_statements](https://www.postgresql.org/docs/13/pgstatstatements.html)
extension by setting something like this in `postgresql.conf` file for
postgresql server to be monitored:
```conf
shared_preload_libraries = pg_stat_statements
track_functions = pl
track_io_timing = on
track_activity_query_size = 2048
pg_stat_statements.track = all
```
Restart postgresql server to make above settings alive.
Setup password for user `pghero` in environment in `.env` file or by
running something like this in terminal
```bash
export BLOCKTRADES_PGHERO_PGHERO_USER_PASSWORD=<secret-password>
export BLOCKTRADES_PGHERO_DATABASE_URL=postgres://pghero:${BLOCKTRADES_PGHERO_PGHERO_USER_PASSWORD}@<PGHOST>:5432/pghero
```
Replace `<secret-password>` with your password. Replace `<PGHOST>` with
host to be monitored.
Run scripts
- blocktrades/pghero/setup/21_create_role_pghero.sql
- blocktrades/pghero/setup/22-pghero-set-password.sh
- blocktrades/pghero/setup/31_setup_monitoring_pghero.sql
against database to be monitored. You can find example run commands at
the top of these files. Other scripts in `blocktrades/pghero/setup`
directory are for having historical data in pghero, and we usually don't
need this functionality.
Start `blocktrades/pghero` service, bind mounting yaml file with
following example contents:
```yaml
databases:
my-monitored-db:
url: <%= ENV["DATABASE_URL"] %>/<my-monitored-db>
```
to the location `/app/config/pghero.yml` in docker container.
```
docker exec -u root haf-instance-5M ./haf/scripts/pghero/setup_pghero.sh --database=test
```

89
scripts/pghero/pghero.sql Normal file
View File

@ -0,0 +1,89 @@
--
-- Installs [pghero](https://github.com/ankane/pghero) monitoring stuff
-- into database.
--
-- Example run: psql -p 5432 -U postgres -h 127.0.0.1 -f ./pghero.sql
--
SET client_encoding = 'UTF8';
SET client_min_messages = 'warning';
BEGIN;
\echo Creating role pghero
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;
COMMENT ON ROLE pghero IS
'Role for monitoring https://github.com/ankane/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$;
\echo Installing monitoring stuff for pghero
CREATE SCHEMA IF NOT EXISTS pghero;
COMMENT ON SCHEMA pghero IS
'Schema contains objects for monitoring https://github.com/ankane/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 OR REPLACE 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 OR REPLACE 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 OR REPLACE 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;

View File

@ -0,0 +1,3 @@
databases:
haf_block_log:
url: <%= ENV["DATABASE_URL"] %>/haf_block_log

82
scripts/pghero/setup_pghero.sh Executable file
View File

@ -0,0 +1,82 @@
#! /bin/bash
SCRIPTPATH="$( cd -- "$(dirname "$0")" >/dev/null 2>&1 ; pwd -P )"
LOG_FILE=setup_pghero.log
source "$SCRIPTPATH/common.sh"
log_exec_params "$@"
#
# Script installs [pghero](https://github.com/ankane/pghero) monitoring
# stuff into specified database. This script execution requires root
# privileges.
#
print_help() {
echo "Usage: $0 [OPTION[=VALUE]]..."
echo
echo "Script installs [pghero](https://github.com/ankane/pghero) monitoring stuff into specified database"
echo "OPTIONS:"
echo " --host=VALUE Allows to specify a PostgreSQL host location (defaults to /var/run/postgresql)"
echo " --port=NUMBER Allows to specify a PostgreSQL operating port (defaults to 5432)"
echo " --database=VALUE Allows to specify a PostgreSQL database (defaults to haf_block_log)"
echo " --help Display this help screen and exit"
echo
}
setup_pghero() {
local pg_access="$1"
echo "Attempting to install pghero stuff"
sudo -nu postgres psql -d postgres -aw $pg_access -v ON_ERROR_STOP=on -f $SCRIPTPATH/pghero/pghero.sql
}
POSTGRES_HOST="/var/run/postgresql"
POSTGRES_PORT=5432
POSTGRES_DATABASE="haf_block_log"
while [ $# -gt 0 ]; do
case "$1" in
--host=*)
POSTGRES_HOST="${1#*=}"
;;
--port=*)
POSTGRES_PORT="${1#*=}"
;;
--database=*)
POSTGRES_DATABASE="${1#*=}"
;;
--help)
print_help
exit 0
;;
-*)
echo "ERROR: '$1' is not a valid option"
echo
print_help
exit 1
;;
*)
echo "ERROR: '$1' is not a valid argument"
echo
print_help
exit 2
;;
esac
shift
done
POSTGRES_ACCESS="--host $POSTGRES_HOST --port $POSTGRES_PORT -d $POSTGRES_DATABASE"
if [ "$EUID" -ne 0 ]
then echo "Please run as root"
exit 1
fi
# Be sure PostgreSQL is started.
/etc/init.d/postgresql start
setup_pghero "$POSTGRES_ACCESS"
# Allow everyone to overwrite/remove our log
chmod a+w "$LOG_FILE"