Skip to content

Commit

Permalink
Make post_init.sh script idempotent (#236)
Browse files Browse the repository at this point in the history
The second run will not produce errors but rather will fix some discrepancies between current and desired state.
In addition to that it makes zmon_utils compatible with postgres >= 10.

On the next step we can call this script after every "promote" event. It will eliminate the need to manually deploy future changes.
  • Loading branch information
CyberDem0n committed May 29, 2018
1 parent 47da157 commit d9a6619
Show file tree
Hide file tree
Showing 2 changed files with 99 additions and 60 deletions.
80 changes: 43 additions & 37 deletions postgres-appliance/_zmon_schema.dump
Original file line number Diff line number Diff line change
@@ -1,9 +1,24 @@
RESET ROLE;
SET ROLE TO postgres;

CREATE LANGUAGE plpython3u;

DROP SCHEMA IF EXISTS zmon_utils CASCADE;

DO $$
BEGIN
PERFORM * FROM pg_catalog.pg_language WHERE lanname = 'plpython3u' AND NOT EXISTS (SELECT 1 FROM pg_catalog.pg_extension WHERE extname = 'plpython3u');
IF FOUND THEN
CREATE EXTENSION plpython3u FROM UNPACKAGED;
ELSE
CREATE EXTENSION IF NOT EXISTS plpython3u;
END IF;
END;$$;

-- remove plpython2 leftovers
DROP LANGUAGE IF EXISTS plpythonu;
DROP FUNCTION IF EXISTS plpython_call_handler();
DROP FUNCTION IF EXISTS plpython_inline_handler(internal);
DROP FUNCTION IF EXISTS plpython_validator(oid);

CREATE SCHEMA zmon_utils;

GRANT USAGE ON SCHEMA zmon_utils TO robot_zmon;
Expand All @@ -24,15 +39,24 @@ DECLARE
wal_delay_seconds BIGINT;
in_recovery BOOLEAN;
xlog_location_string TEXT;
receive_location TEXT;
server_version_num INTEGER;
nosync INTEGER;
BEGIN
server_version_num := current_setting('server_version_num')::integer;
SELECT pg_is_in_recovery() INTO in_recovery;
SELECT
CASE WHEN in_recovery THEN pg_last_xlog_replay_location()
ELSE pg_current_xlog_location()
END INTO xlog_location_string;
IF server_version_num >= 100000
THEN
SELECT CASE WHEN in_recovery THEN pg_last_wal_replay_lsn()
ELSE pg_current_wal_lsn()
END INTO xlog_location_string;
SELECT pg_last_wal_receive_lsn() INTO receive_location;
ELSE
SELECT CASE WHEN in_recovery THEN pg_last_xlog_replay_location()
ELSE pg_current_xlog_location()
END INTO xlog_location_string;
SELECT pg_last_xlog_receive_location() INTO receive_location;
END IF;
SELECT ('x'||lpad(split_part(xlog_location_string, '/', 1), 16, '0'))::bit(64)::bigint INTO wal_segment;
SELECT ('x'||lpad(split_part(xlog_location_string, '/', 2), 16, '0'))::bit(64)::bigint INTO wal_offset;
SELECT 1 FROM pg_ls_dir('.') as t(name) WHERE name = 'dontsync' INTO nosync;
Expand Down Expand Up @@ -76,7 +100,7 @@ BEGIN
'synchronous_commit'
)
UNION ALL
SELECT 'cluster_name', substring(s.setting from E'/pgsql_([^/]+)/[^/]+/data$')
SELECT 'cluster_name', COALESCE(CASE WHEN server_version_num >= 90500 THEN current_setting('cluster_name') ELSE NULL END, substring(s.setting from E'/pgsql_([^/]+)/[^/]+/data$'))
FROM pg_settings as s
WHERE s.name = 'data_directory'
UNION ALL
Expand All @@ -92,7 +116,7 @@ BEGIN
UNION ALL
SELECT 'wal_delay_seconds' as name, wal_delay_seconds::text
UNION ALL
SELECT 'is_streaming' as name, CAST(pg_last_xlog_receive_location() IS NOT NULL AND in_recovery AS TEXT) as setting
SELECT 'is_streaming' as name, CAST(receive_location IS NOT NULL AND in_recovery AS TEXT) as setting
UNION ALL
SELECT 'archive_nosync' as name, CAST(nosync IS NOT NULL AS TEXT) as setting;
-- pg_stat_activity column names differ depending on server version
Expand Down Expand Up @@ -138,11 +162,8 @@ BEGIN
END
$BODY$
LANGUAGE plpgsql
SECURITY DEFINER;
DO $DO$
BEGIN

IF EXISTS( SELECT 1 FROM pg_language WHERE lanname = 'plpython3u' ) THEN
SECURITY DEFINER
SET search_path to 'pg_catalog';

CREATE OR REPLACE FUNCTION zmon_utils.get_database_cluster_system_information()
RETURNS SETOF zmon_utils.system_information
Expand Down Expand Up @@ -366,7 +387,7 @@ def get_vm_info():
'/proc/sys/vm/overcommit_ratio' : 'vm.overcommit_ratio'
}
try:
for fname, kname in file_keys.tems():
for fname, kname in file_keys.items():
try:
fp = open(fname, 'r')
val = int(fp.read().strip())
Expand All @@ -380,7 +401,7 @@ def get_vm_info():
if "stmt_settings" in SD:
plan = SD["stmt_settings"]
else:
plan = plpy.prepare("SELECT name, setting FROM pg_catalog.pg_settings WHERE name in ('data_directory', 'log_directory')")
plan = plpy.prepare("SELECT name, setting FROM pg_catalog.pg_settings WHERE name in ('data_directory', 'log_directory', 'server_version_num')")
SD["stmt_settings"] = plan

rv = plpy.execute(plan)
Expand All @@ -391,7 +412,7 @@ for r in rv:
data_directory = s["data_directory"]
log_directory = s["log_directory"] = os.path.join(data_directory, s["log_directory"])
pg_tblspc = os.path.join(data_directory, "pg_tblspc")
pg_xlog = os.path.join(data_directory, "pg_xlog")
pg_xlog = os.path.join(data_directory, "pg_xlog" if int(s["server_version_num"]) < 100000 else "pg_wal")

result = {}

Expand All @@ -402,9 +423,10 @@ if len(ts_stats) > 0:

#get xlog and log directories
for (path, prefix) in ((pg_xlog, 'xlog'), (log_directory, 'log')):
stats = collect_directory_stats(path, prefix)
if len(stats) > 0:
result.update(stats)
if os.path.isdir(path):
stats = collect_directory_stats(path, prefix)
if len(stats) > 0:
result.update(stats)

result.update(get_platform_information())
result.update(get_load_average())
Expand All @@ -420,23 +442,7 @@ return result.items()

$BODY$
LANGUAGE plpython3u
SECURITY DEFINER;

ELSE -- there is not plpython3u installation on that machine

CREATE OR REPLACE FUNCTION zmon_utils.get_database_cluster_system_information()
RETURNS SETOF system_information
AS
$BODY$
BEGIN
RETURN QUERY SELECT 'error'::text, 'plpython3u not installed'::text;
END;
$BODY$
LANGUAGE plpgsql
SECURITY DEFINER;

END IF;
END;
$DO$;
SECURITY DEFINER
SET search_path to 'pg_catalog';
grant execute on all functions in schema zmon_utils to robot_zmon;

79 changes: 56 additions & 23 deletions postgres-appliance/post_init.sh
Original file line number Diff line number Diff line change
@@ -1,10 +1,36 @@
#!/bin/bash

(echo "CREATE ROLE admin CREATEDB NOLOGIN;
CREATE ROLE $1;
CREATE ROLE robot_zmon;
(echo "DO \$\$
BEGIN
PERFORM * FROM pg_catalog.pg_authid WHERE rolname = 'admin';
IF FOUND THEN
ALTER ROLE admin WITH CREATEDB NOLOGIN NOCREATEROLE NOSUPERUSER NOREPLICATION INHERIT;
ELSE
CREATE ROLE admin CREATEDB;
END IF;
END;\$\$;
CREATE EXTENSION pg_cron;
DO \$\$
BEGIN
PERFORM * FROM pg_catalog.pg_authid WHERE rolname = '$1';
IF FOUND THEN
ALTER ROLE $1 WITH NOCREATEDB NOLOGIN NOCREATEROLE NOSUPERUSER NOREPLICATION INHERIT;
ELSE
CREATE ROLE $1;
END IF;
END;\$\$;
DO \$\$
BEGIN
PERFORM * FROM pg_catalog.pg_authid WHERE rolname = 'robot_zmon';
IF FOUND THEN
ALTER ROLE robot_zmon WITH NOCREATEDB NOLOGIN NOCREATEROLE NOSUPERUSER NOREPLICATION INHERIT;
ELSE
CREATE ROLE robot_zmon;
END IF;
END;\$\$;
CREATE EXTENSION IF NOT EXISTS pg_cron SCHEMA public;
ALTER POLICY cron_job_policy ON cron.job USING (username = current_user OR
(pg_has_role(current_user, 'admin', 'MEMBER')
Expand Down Expand Up @@ -39,9 +65,16 @@ REVOKE EXECUTE ON FUNCTION cron.unschedule(bigint) FROM public;
GRANT EXECUTE ON FUNCTION cron.unschedule(bigint) TO admin;
GRANT USAGE ON SCHEMA cron TO admin;
CREATE EXTENSION file_fdw;
CREATE SERVER pglog FOREIGN DATA WRAPPER file_fdw;
CREATE TABLE postgres_log (
CREATE EXTENSION IF NOT EXISTS file_fdw SCHEMA public;
DO \$\$
BEGIN
PERFORM * FROM pg_catalog.pg_foreign_server WHERE srvname = 'pglog';
IF NOT FOUND THEN
CREATE SERVER pglog FOREIGN DATA WRAPPER file_fdw;
END IF;
END;\$\$;
CREATE TABLE IF NOT EXISTS public.postgres_log (
log_time timestamp(3) with time zone,
user_name text,
database_name text,
Expand All @@ -67,31 +100,31 @@ CREATE TABLE postgres_log (
application_name text,
CONSTRAINT postgres_log_check CHECK (false) NO INHERIT
);
GRANT SELECT ON postgres_log TO admin;"
GRANT SELECT ON public.postgres_log TO admin;"

# Sunday could be 0 or 7 depending on the format, we just create both
for i in $(seq 0 7); do
echo "CREATE FOREIGN TABLE postgres_log_$i () INHERITS (postgres_log) SERVER pglog
echo "CREATE FOREIGN TABLE IF NOT EXISTS public.postgres_log_$i () INHERITS (public.postgres_log) SERVER pglog
OPTIONS (filename '../pg_log/postgresql-$i.csv', format 'csv', header 'false');
GRANT SELECT ON postgres_log_$i TO admin;
GRANT SELECT ON public.postgres_log_$i TO admin;
CREATE OR REPLACE VIEW failed_authentication_$i WITH (security_barrier) AS
CREATE OR REPLACE VIEW public.failed_authentication_$i WITH (security_barrier) AS
SELECT *
FROM postgres_log_$i
FROM public.postgres_log_$i
WHERE command_tag = 'authentication'
AND error_severity = 'FATAL';
ALTER VIEW failed_authentication_$i OWNER TO postgres;
GRANT SELECT ON TABLE failed_authentication_$i TO robot_zmon;
ALTER VIEW public.failed_authentication_$i OWNER TO postgres;
GRANT SELECT ON TABLE public.failed_authentication_$i TO robot_zmon;
"
done

cat /_zmon_schema.dump

sed "s/:HUMAN_ROLE/$1/" /create_user_functions.sql

echo "\c template1
CREATE EXTENSION pg_stat_statements;
CREATE EXTENSION set_user;
GRANT EXECUTE ON FUNCTION set_user(text) TO admin;"
cat _zmon_schema.dump

sed "s/:HUMAN_ROLE/$1/" /create_user_functions.sql) | psql -d $2
while IFS= read -r db_name; do
echo "\c ${db_name}"
sed "s/:HUMAN_ROLE/$1/" create_user_functions.sql
echo "CREATE EXTENSION IF NOT EXISTS pg_stat_statements SCHEMA public;
CREATE EXTENSION IF NOT EXISTS set_user SCHEMA public;
GRANT EXECUTE ON FUNCTION public.set_user(text) TO admin;"
done < <(psql -d $2 -tAc 'select pg_catalog.quote_ident(datname) from pg_database where datallowconn')
) | psql -d $2

0 comments on commit d9a6619

Please sign in to comment.