--- apiVersion: v1 kind: ConfigMap metadata: name: postgresql-connection-metrics namespace: postgresql-system labels: cnpg.io/reload: "" # Enable automatic reload data: custom-queries: | pg_application_connections: query: "SELECT COALESCE(NULLIF(application_name, ''), 'unknown') AS app_name, state, COUNT(*) AS connection_count FROM pg_stat_activity WHERE state IS NOT NULL AND pid != pg_backend_pid() GROUP BY COALESCE(NULLIF(application_name, ''), 'unknown'), state" metrics: - app_name: usage: "LABEL" description: "Application name from connection" - state: usage: "LABEL" description: "Connection state (active, idle, idle_in_transaction, etc)" - connection_count: usage: "GAUGE" description: "Number of connections per application and state" pg_database_connections: query: "SELECT datname AS database_name, COALESCE(NULLIF(application_name, ''), 'unknown') AS app_name, COUNT(*) AS connection_count FROM pg_stat_activity WHERE datname IS NOT NULL AND pid != pg_backend_pid() GROUP BY datname, COALESCE(NULLIF(application_name, ''), 'unknown')" metrics: - database_name: usage: "LABEL" description: "Database name" - app_name: usage: "LABEL" description: "Application name from connection" - connection_count: usage: "GAUGE" description: "Number of connections per database and application" pg_connection_states: query: "SELECT state, COUNT(*) AS connection_count, COUNT(*) FILTER (WHERE COALESCE(NULLIF(application_name, ''), 'unknown') != 'unknown') AS named_connections, COUNT(*) FILTER (WHERE COALESCE(NULLIF(application_name, ''), 'unknown') = 'unknown') AS unnamed_connections FROM pg_stat_activity WHERE state IS NOT NULL AND pid != pg_backend_pid() GROUP BY state" metrics: - state: usage: "LABEL" description: "Connection state" - connection_count: usage: "GAUGE" description: "Total connections in this state" - named_connections: usage: "GAUGE" description: "Connections with application_name set" - unnamed_connections: usage: "GAUGE" description: "Connections without application_name" pg_user_connections: query: "SELECT usename AS username, COUNT(*) AS connection_count FROM pg_stat_activity WHERE usename IS NOT NULL AND pid != pg_backend_pid() GROUP BY usename" metrics: - username: usage: "LABEL" description: "PostgreSQL username" - connection_count: usage: "GAUGE" description: "Number of connections per user" pg_long_running_queries: query: "SELECT datname AS database_name, usename AS username, COALESCE(NULLIF(application_name, ''), 'unknown') AS app_name, state, COALESCE(EXTRACT(EPOCH FROM (now() - query_start))::numeric, 0) AS query_duration_seconds, COALESCE(EXTRACT(EPOCH FROM (now() - state_change))::numeric, 0) AS state_duration_seconds, CASE WHEN state_change IS NOT NULL AND query_start IS NOT NULL THEN COALESCE(EXTRACT(EPOCH FROM (state_change - query_start))::numeric, 0) ELSE 0 END AS execution_time_seconds, COALESCE(wait_event_type, 'none') AS wait_event_type, CASE WHEN query LIKE 'SELECT%' THEN 'SELECT' WHEN query LIKE 'INSERT%' THEN 'INSERT' WHEN query LIKE 'UPDATE%' THEN 'UPDATE' WHEN query LIKE 'DELETE%' THEN 'DELETE' WHEN query LIKE 'CREATE%' THEN 'CREATE' WHEN query LIKE 'ALTER%' THEN 'ALTER' WHEN query LIKE 'DROP%' THEN 'DROP' ELSE 'OTHER' END AS query_type, LEFT( CASE WHEN query ILIKE 'SELECT%' AND position('FROM' in UPPER(query)) > 0 THEN 'SELECT (...) ' || SUBSTRING(query FROM position('FROM' in UPPER(query))) WHEN query ILIKE 'UPDATE%' AND position('UPDATE' in UPPER(query)) > 0 THEN SUBSTRING(query FROM position('UPDATE' in UPPER(query))) WHEN query ILIKE 'INSERT%' AND position('INTO' in UPPER(query)) > 0 THEN SUBSTRING(query FROM position('INTO' in UPPER(query))) WHEN query ILIKE 'DELETE%' AND position('FROM' in UPPER(query)) > 0 THEN 'DELETE (...) ' || SUBSTRING(query FROM position('FROM' in UPPER(query))) ELSE query END, 8000 ) AS query_context FROM pg_stat_activity WHERE state != 'idle' AND pid != pg_backend_pid() AND query_start IS NOT NULL AND EXTRACT(EPOCH FROM (now() - query_start)) > 5.0 ORDER BY query_start ASC" metrics: - database_name: usage: "LABEL" description: "Database name" - username: usage: "LABEL" description: "PostgreSQL username" - app_name: usage: "LABEL" description: "Application name" - state: usage: "LABEL" description: "Query state (active, idle_in_transaction, etc)" - query_duration_seconds: usage: "GAUGE" description: "Time in seconds since query started" - state_duration_seconds: usage: "GAUGE" description: "Time in seconds since last state change (client wait time for 'Client' wait events)" - execution_time_seconds: usage: "GAUGE" description: "Actual query execution time in seconds (state_change - query_start)" - wait_event_type: usage: "LABEL" description: "Type of event the backend is waiting for" - query_type: usage: "LABEL" description: "Type of SQL query (SELECT, INSERT, UPDATE, etc)" - query_context: usage: "LABEL" description: "Query clause after SELECT (FROM/WHERE/etc)" pg_active_query_stats: query: "SELECT state, COUNT(*) AS query_count, MAX(COALESCE(EXTRACT(EPOCH FROM (now() - query_start))::numeric, 0)) AS max_duration_seconds, AVG(COALESCE(EXTRACT(EPOCH FROM (now() - query_start))::numeric, 0)) AS avg_duration_seconds FROM pg_stat_activity WHERE state != 'idle' AND pid != pg_backend_pid() AND query_start IS NOT NULL GROUP BY state" metrics: - state: usage: "LABEL" description: "Query state" - query_count: usage: "GAUGE" description: "Number of queries in this state" - max_duration_seconds: usage: "GAUGE" description: "Maximum query duration in seconds" - avg_duration_seconds: usage: "GAUGE" description: "Average query duration in seconds"