postgres.chart.py 46 KB

12345678910111213141516171819202122232425262728293031323334353637383940414243444546474849505152535455565758596061626364656667686970717273747576777879808182838485868788899091929394959697989910010110210310410510610710810911011111211311411511611711811912012112212312412512612712812913013113213313413513613713813914014114214314414514614714814915015115215315415515615715815916016116216316416516616716816917017117217317417517617717817918018118218318418518618718818919019119219319419519619719819920020120220320420520620720820921021121221321421521621721821922022122222322422522622722822923023123223323423523623723823924024124224324424524624724824925025125225325425525625725825926026126226326426526626726826927027127227327427527627727827928028128228328428528628728828929029129229329429529629729829930030130230330430530630730830931031131231331431531631731831932032132232332432532632732832933033133233333433533633733833934034134234334434534634734834935035135235335435535635735835936036136236336436536636736836937037137237337437537637737837938038138238338438538638738838939039139239339439539639739839940040140240340440540640740840941041141241341441541641741841942042142242342442542642742842943043143243343443543643743843944044144244344444544644744844945045145245345445545645745845946046146246346446546646746846947047147247347447547647747847948048148248348448548648748848949049149249349449549649749849950050150250350450550650750850951051151251351451551651751851952052152252352452552652752852953053153253353453553653753853954054154254354454554654754854955055155255355455555655755855956056156256356456556656756856957057157257357457557657757857958058158258358458558658758858959059159259359459559659759859960060160260360460560660760860961061161261361461561661761861962062162262362462562662762862963063163263363463563663763863964064164264364464564664764864965065165265365465565665765865966066166266366466566666766866967067167267367467567667767867968068168268368468568668768868969069169269369469569669769869970070170270370470570670770870971071171271371471571671771871972072172272372472572672772872973073173273373473573673773873974074174274374474574674774874975075175275375475575675775875976076176276376476576676776876977077177277377477577677777877978078178278378478578678778878979079179279379479579679779879980080180280380480580680780880981081181281381481581681781881982082182282382482582682782882983083183283383483583683783883984084184284384484584684784884985085185285385485585685785885986086186286386486586686786886987087187287387487587687787887988088188288388488588688788888989089189289389489589689789889990090190290390490590690790890991091191291391491591691791891992092192292392492592692792892993093193293393493593693793893994094194294394494594694794894995095195295395495595695795895996096196296396496596696796896997097197297397497597697797897998098198298398498598698798898999099199299399499599699799899910001001100210031004100510061007100810091010101110121013101410151016101710181019102010211022102310241025102610271028102910301031103210331034103510361037103810391040104110421043104410451046104710481049105010511052105310541055105610571058105910601061106210631064106510661067106810691070107110721073107410751076107710781079108010811082108310841085108610871088108910901091109210931094109510961097109810991100110111021103110411051106110711081109111011111112111311141115111611171118111911201121112211231124112511261127112811291130113111321133113411351136113711381139114011411142114311441145114611471148114911501151115211531154115511561157115811591160116111621163116411651166116711681169117011711172117311741175117611771178117911801181118211831184118511861187118811891190119111921193119411951196119711981199120012011202120312041205120612071208120912101211121212131214121512161217121812191220122112221223122412251226122712281229123012311232123312341235123612371238123912401241124212431244124512461247124812491250125112521253125412551256125712581259126012611262126312641265126612671268126912701271127212731274127512761277127812791280128112821283128412851286128712881289129012911292129312941295129612971298129913001301130213031304130513061307130813091310131113121313131413151316131713181319132013211322132313241325132613271328132913301331133213331334133513361337133813391340134113421343134413451346134713481349135013511352135313541355135613571358135913601361136213631364136513661367136813691370137113721373137413751376137713781379138013811382138313841385138613871388138913901391139213931394139513961397139813991400140114021403140414051406140714081409141014111412141314141415141614171418141914201421142214231424142514261427142814291430143114321433143414351436
  1. # -*- coding: utf-8 -*-
  2. # Description: example netdata python.d module
  3. # Authors: facetoe, dangtranhoang
  4. # SPDX-License-Identifier: GPL-3.0-or-later
  5. from copy import deepcopy
  6. try:
  7. import psycopg2
  8. from psycopg2 import extensions
  9. from psycopg2.extras import DictCursor
  10. from psycopg2 import OperationalError
  11. PSYCOPG2 = True
  12. except ImportError:
  13. PSYCOPG2 = False
  14. from bases.FrameworkServices.SimpleService import SimpleService
  15. DEFAULT_PORT = 5432
  16. DEFAULT_USER = 'postgres'
  17. DEFAULT_CONNECT_TIMEOUT = 2 # seconds
  18. DEFAULT_STATEMENT_TIMEOUT = 5000 # ms
  19. CONN_PARAM_DSN = 'dsn'
  20. CONN_PARAM_HOST = 'host'
  21. CONN_PARAM_PORT = 'port'
  22. CONN_PARAM_DATABASE = 'database'
  23. CONN_PARAM_USER = 'user'
  24. CONN_PARAM_PASSWORD = 'password'
  25. CONN_PARAM_CONN_TIMEOUT = 'connect_timeout'
  26. CONN_PARAM_STATEMENT_TIMEOUT = 'statement_timeout'
  27. CONN_PARAM_SSL_MODE = 'sslmode'
  28. CONN_PARAM_SSL_ROOT_CERT = 'sslrootcert'
  29. CONN_PARAM_SSL_CRL = 'sslcrl'
  30. CONN_PARAM_SSL_CERT = 'sslcert'
  31. CONN_PARAM_SSL_KEY = 'sslkey'
  32. QUERY_NAME_WAL = 'WAL'
  33. QUERY_NAME_ARCHIVE = 'ARCHIVE'
  34. QUERY_NAME_BACKENDS = 'BACKENDS'
  35. QUERY_NAME_BACKEND_USAGE = 'BACKEND_USAGE'
  36. QUERY_NAME_TABLE_STATS = 'TABLE_STATS'
  37. QUERY_NAME_INDEX_STATS = 'INDEX_STATS'
  38. QUERY_NAME_DATABASE = 'DATABASE'
  39. QUERY_NAME_BGWRITER = 'BGWRITER'
  40. QUERY_NAME_LOCKS = 'LOCKS'
  41. QUERY_NAME_BLOCKERS = 'BLOCKERS'
  42. QUERY_NAME_DATABASES = 'DATABASES'
  43. QUERY_NAME_STANDBY = 'STANDBY'
  44. QUERY_NAME_REPLICATION_SLOT = 'REPLICATION_SLOT'
  45. QUERY_NAME_STANDBY_DELTA = 'STANDBY_DELTA'
  46. QUERY_NAME_STANDBY_LAG = 'STANDBY_LAG'
  47. QUERY_NAME_REPSLOT_FILES = 'REPSLOT_FILES'
  48. QUERY_NAME_IF_SUPERUSER = 'IF_SUPERUSER'
  49. QUERY_NAME_SERVER_VERSION = 'SERVER_VERSION'
  50. QUERY_NAME_AUTOVACUUM = 'AUTOVACUUM'
  51. QUERY_NAME_FORCED_AUTOVACUUM = 'FORCED_AUTOVACUUM'
  52. QUERY_NAME_TX_WRAPAROUND = 'TX_WRAPAROUND'
  53. QUERY_NAME_DIFF_LSN = 'DIFF_LSN'
  54. QUERY_NAME_WAL_WRITES = 'WAL_WRITES'
  55. METRICS = {
  56. QUERY_NAME_DATABASE: [
  57. 'connections',
  58. 'xact_commit',
  59. 'xact_rollback',
  60. 'blks_read',
  61. 'blks_hit',
  62. 'tup_returned',
  63. 'tup_fetched',
  64. 'tup_inserted',
  65. 'tup_updated',
  66. 'tup_deleted',
  67. 'conflicts',
  68. 'temp_files',
  69. 'temp_bytes',
  70. 'size'
  71. ],
  72. QUERY_NAME_BACKENDS: [
  73. 'backends_active',
  74. 'backends_idle'
  75. ],
  76. QUERY_NAME_BACKEND_USAGE: [
  77. 'available',
  78. 'used'
  79. ],
  80. QUERY_NAME_INDEX_STATS: [
  81. 'index_count',
  82. 'index_size'
  83. ],
  84. QUERY_NAME_TABLE_STATS: [
  85. 'table_size',
  86. 'table_count'
  87. ],
  88. QUERY_NAME_WAL: [
  89. 'written_wal',
  90. 'recycled_wal',
  91. 'total_wal'
  92. ],
  93. QUERY_NAME_WAL_WRITES: [
  94. 'wal_writes'
  95. ],
  96. QUERY_NAME_ARCHIVE: [
  97. 'ready_count',
  98. 'done_count',
  99. 'file_count'
  100. ],
  101. QUERY_NAME_BGWRITER: [
  102. 'checkpoint_scheduled',
  103. 'checkpoint_requested',
  104. 'buffers_checkpoint',
  105. 'buffers_clean',
  106. 'maxwritten_clean',
  107. 'buffers_backend',
  108. 'buffers_alloc',
  109. 'buffers_backend_fsync'
  110. ],
  111. QUERY_NAME_LOCKS: [
  112. 'ExclusiveLock',
  113. 'RowShareLock',
  114. 'SIReadLock',
  115. 'ShareUpdateExclusiveLock',
  116. 'AccessExclusiveLock',
  117. 'AccessShareLock',
  118. 'ShareRowExclusiveLock',
  119. 'ShareLock',
  120. 'RowExclusiveLock'
  121. ],
  122. QUERY_NAME_BLOCKERS: [
  123. 'blocking_pids_avg'
  124. ],
  125. QUERY_NAME_AUTOVACUUM: [
  126. 'analyze',
  127. 'vacuum_analyze',
  128. 'vacuum',
  129. 'vacuum_freeze',
  130. 'brin_summarize'
  131. ],
  132. QUERY_NAME_FORCED_AUTOVACUUM: [
  133. 'percent_towards_forced_vacuum'
  134. ],
  135. QUERY_NAME_TX_WRAPAROUND: [
  136. 'oldest_current_xid',
  137. 'percent_towards_wraparound'
  138. ],
  139. QUERY_NAME_STANDBY_DELTA: [
  140. 'sent_delta',
  141. 'write_delta',
  142. 'flush_delta',
  143. 'replay_delta'
  144. ],
  145. QUERY_NAME_STANDBY_LAG: [
  146. 'write_lag',
  147. 'flush_lag',
  148. 'replay_lag'
  149. ],
  150. QUERY_NAME_REPSLOT_FILES: [
  151. 'replslot_wal_keep',
  152. 'replslot_files'
  153. ]
  154. }
  155. NO_VERSION = 0
  156. DEFAULT = 'DEFAULT'
  157. V72 = 'V72'
  158. V82 = 'V82'
  159. V91 = 'V91'
  160. V92 = 'V92'
  161. V96 = 'V96'
  162. V10 = 'V10'
  163. V11 = 'V11'
  164. QUERY_WAL = {
  165. DEFAULT: """
  166. SELECT
  167. count(*) as total_wal,
  168. count(*) FILTER (WHERE type = 'recycled') AS recycled_wal,
  169. count(*) FILTER (WHERE type = 'written') AS written_wal
  170. FROM
  171. (SELECT
  172. wal.name,
  173. pg_walfile_name(
  174. CASE pg_is_in_recovery()
  175. WHEN true THEN NULL
  176. ELSE pg_current_wal_lsn()
  177. END ),
  178. CASE
  179. WHEN wal.name > pg_walfile_name(
  180. CASE pg_is_in_recovery()
  181. WHEN true THEN NULL
  182. ELSE pg_current_wal_lsn()
  183. END ) THEN 'recycled'
  184. ELSE 'written'
  185. END AS type
  186. FROM pg_catalog.pg_ls_dir('pg_wal') AS wal(name)
  187. WHERE name ~ '^[0-9A-F]{24}$'
  188. ORDER BY
  189. (pg_stat_file('pg_wal/'||name, true)).modification,
  190. wal.name DESC) sub;
  191. """,
  192. V96: """
  193. SELECT
  194. count(*) as total_wal,
  195. count(*) FILTER (WHERE type = 'recycled') AS recycled_wal,
  196. count(*) FILTER (WHERE type = 'written') AS written_wal
  197. FROM
  198. (SELECT
  199. wal.name,
  200. pg_xlogfile_name(
  201. CASE pg_is_in_recovery()
  202. WHEN true THEN NULL
  203. ELSE pg_current_xlog_location()
  204. END ),
  205. CASE
  206. WHEN wal.name > pg_xlogfile_name(
  207. CASE pg_is_in_recovery()
  208. WHEN true THEN NULL
  209. ELSE pg_current_xlog_location()
  210. END ) THEN 'recycled'
  211. ELSE 'written'
  212. END AS type
  213. FROM pg_catalog.pg_ls_dir('pg_xlog') AS wal(name)
  214. WHERE name ~ '^[0-9A-F]{24}$'
  215. ORDER BY
  216. (pg_stat_file('pg_xlog/'||name, true)).modification,
  217. wal.name DESC) sub;
  218. """,
  219. }
  220. QUERY_ARCHIVE = {
  221. DEFAULT: """
  222. SELECT
  223. CAST(COUNT(*) AS INT) AS file_count,
  224. CAST(COALESCE(SUM(CAST(archive_file ~ $r$\.ready$$r$ as INT)),0) AS INT) AS ready_count,
  225. CAST(COALESCE(SUM(CAST(archive_file ~ $r$\.done$$r$ AS INT)),0) AS INT) AS done_count
  226. FROM
  227. pg_catalog.pg_ls_dir('pg_wal/archive_status') AS archive_files (archive_file);
  228. """,
  229. V96: """
  230. SELECT
  231. CAST(COUNT(*) AS INT) AS file_count,
  232. CAST(COALESCE(SUM(CAST(archive_file ~ $r$\.ready$$r$ as INT)),0) AS INT) AS ready_count,
  233. CAST(COALESCE(SUM(CAST(archive_file ~ $r$\.done$$r$ AS INT)),0) AS INT) AS done_count
  234. FROM
  235. pg_catalog.pg_ls_dir('pg_xlog/archive_status') AS archive_files (archive_file);
  236. """,
  237. }
  238. QUERY_BACKEND = {
  239. DEFAULT: """
  240. SELECT
  241. count(*) - (SELECT count(*)
  242. FROM pg_stat_activity
  243. WHERE state = 'idle')
  244. AS backends_active,
  245. (SELECT count(*)
  246. FROM pg_stat_activity
  247. WHERE state = 'idle')
  248. AS backends_idle
  249. FROM pg_stat_activity;
  250. """,
  251. }
  252. QUERY_BACKEND_USAGE = {
  253. DEFAULT: """
  254. SELECT
  255. COUNT(1) as used,
  256. current_setting('max_connections')::int - current_setting('superuser_reserved_connections')::int
  257. - COUNT(1) AS available
  258. FROM pg_catalog.pg_stat_activity
  259. WHERE backend_type IN ('client backend', 'background worker');
  260. """,
  261. V10: """
  262. SELECT
  263. SUM(s.conn) as used,
  264. current_setting('max_connections')::int - current_setting('superuser_reserved_connections')::int
  265. - SUM(s.conn) AS available
  266. FROM (
  267. SELECT 's' as type, COUNT(1) as conn
  268. FROM pg_catalog.pg_stat_activity
  269. WHERE backend_type IN ('client backend', 'background worker')
  270. UNION ALL
  271. SELECT 'r', COUNT(1)
  272. FROM pg_catalog.pg_stat_replication
  273. ) as s;
  274. """,
  275. V92: """
  276. SELECT
  277. SUM(s.conn) as used,
  278. current_setting('max_connections')::int - current_setting('superuser_reserved_connections')::int
  279. - SUM(s.conn) AS available
  280. FROM (
  281. SELECT 's' as type, COUNT(1) as conn
  282. FROM pg_catalog.pg_stat_activity
  283. WHERE query NOT LIKE 'autovacuum: %%'
  284. UNION ALL
  285. SELECT 'r', COUNT(1)
  286. FROM pg_catalog.pg_stat_replication
  287. ) as s;
  288. """,
  289. V91: """
  290. SELECT
  291. SUM(s.conn) as used,
  292. current_setting('max_connections')::int - current_setting('superuser_reserved_connections')::int
  293. - SUM(s.conn) AS available
  294. FROM (
  295. SELECT 's' as type, COUNT(1) as conn
  296. FROM pg_catalog.pg_stat_activity
  297. WHERE current_query NOT LIKE 'autovacuum: %%'
  298. UNION ALL
  299. SELECT 'r', COUNT(1)
  300. FROM pg_catalog.pg_stat_replication
  301. ) as s;
  302. """,
  303. V82: """
  304. SELECT
  305. COUNT(1) as used,
  306. current_setting('max_connections')::int - current_setting('superuser_reserved_connections')::int
  307. - COUNT(1) AS available
  308. FROM pg_catalog.pg_stat_activity
  309. WHERE current_query NOT LIKE 'autovacuum: %%';
  310. """,
  311. V72: """
  312. SELECT
  313. COUNT(1) as used,
  314. current_setting('max_connections')::int - current_setting('superuser_reserved_connections')::int
  315. - COUNT(1) AS available
  316. FROM pg_catalog.pg_stat_activity s
  317. JOIN pg_catalog.pg_database d ON d.oid = s.datid
  318. WHERE d.datallowconn;
  319. """,
  320. }
  321. QUERY_TABLE_STATS = {
  322. DEFAULT: """
  323. SELECT
  324. sum(relpages) * current_setting('block_size')::numeric AS table_size,
  325. count(1) AS table_count
  326. FROM pg_class
  327. WHERE relkind IN ('r', 't', 'm');
  328. """,
  329. }
  330. QUERY_INDEX_STATS = {
  331. DEFAULT: """
  332. SELECT
  333. sum(relpages) * current_setting('block_size')::numeric AS index_size,
  334. count(1) AS index_count
  335. FROM pg_class
  336. WHERE relkind = 'i';
  337. """,
  338. }
  339. QUERY_DATABASE = {
  340. DEFAULT: """
  341. SELECT
  342. datname AS database_name,
  343. numbackends AS connections,
  344. xact_commit AS xact_commit,
  345. xact_rollback AS xact_rollback,
  346. blks_read AS blks_read,
  347. blks_hit AS blks_hit,
  348. tup_returned AS tup_returned,
  349. tup_fetched AS tup_fetched,
  350. tup_inserted AS tup_inserted,
  351. tup_updated AS tup_updated,
  352. tup_deleted AS tup_deleted,
  353. conflicts AS conflicts,
  354. pg_database_size(datname) AS size,
  355. temp_files AS temp_files,
  356. temp_bytes AS temp_bytes
  357. FROM pg_stat_database
  358. WHERE datname IN %(databases)s ;
  359. """,
  360. }
  361. QUERY_BGWRITER = {
  362. DEFAULT: """
  363. SELECT
  364. checkpoints_timed AS checkpoint_scheduled,
  365. checkpoints_req AS checkpoint_requested,
  366. buffers_checkpoint * current_setting('block_size')::numeric buffers_checkpoint,
  367. buffers_clean * current_setting('block_size')::numeric buffers_clean,
  368. maxwritten_clean,
  369. buffers_backend * current_setting('block_size')::numeric buffers_backend,
  370. buffers_alloc * current_setting('block_size')::numeric buffers_alloc,
  371. buffers_backend_fsync
  372. FROM pg_stat_bgwriter;
  373. """,
  374. }
  375. QUERY_LOCKS = {
  376. DEFAULT: """
  377. SELECT
  378. pg_database.datname as database_name,
  379. mode,
  380. count(mode) AS locks_count
  381. FROM pg_locks
  382. INNER JOIN pg_database
  383. ON pg_database.oid = pg_locks.database
  384. GROUP BY datname, mode
  385. ORDER BY datname, mode;
  386. """,
  387. }
  388. QUERY_BLOCKERS = {
  389. DEFAULT: """
  390. WITH B AS (
  391. SELECT DISTINCT
  392. pg_database.datname as database_name,
  393. pg_locks.pid,
  394. cardinality(pg_blocking_pids(pg_locks.pid)) AS blocking_pids
  395. FROM pg_locks
  396. INNER JOIN pg_database ON pg_database.oid = pg_locks.database
  397. WHERE NOT pg_locks.granted)
  398. SELECT database_name, AVG(blocking_pids) AS blocking_pids_avg
  399. FROM B
  400. GROUP BY database_name
  401. """,
  402. V96: """
  403. WITH B AS (
  404. SELECT DISTINCT
  405. pg_database.datname as database_name,
  406. blocked_locks.pid AS blocked_pid,
  407. COUNT(blocking_locks.pid) AS blocking_pids
  408. FROM pg_catalog.pg_locks blocked_locks
  409. INNER JOIN pg_database ON pg_database.oid = blocked_locks.database
  410. JOIN pg_catalog.pg_locks blocking_locks
  411. ON blocking_locks.locktype = blocked_locks.locktype
  412. AND blocking_locks.database IS NOT DISTINCT FROM blocked_locks.database
  413. AND blocking_locks.relation IS NOT DISTINCT FROM blocked_locks.relation
  414. AND blocking_locks.page IS NOT DISTINCT FROM blocked_locks.page
  415. AND blocking_locks.tuple IS NOT DISTINCT FROM blocked_locks.tuple
  416. AND blocking_locks.virtualxid IS NOT DISTINCT FROM blocked_locks.virtualxid
  417. AND blocking_locks.transactionid IS NOT DISTINCT FROM blocked_locks.transactionid
  418. AND blocking_locks.classid IS NOT DISTINCT FROM blocked_locks.classid
  419. AND blocking_locks.objid IS NOT DISTINCT FROM blocked_locks.objid
  420. AND blocking_locks.objsubid IS NOT DISTINCT FROM blocked_locks.objsubid
  421. AND blocking_locks.pid != blocked_locks.pid
  422. WHERE NOT blocked_locks.GRANTED
  423. GROUP BY database_name, blocked_pid)
  424. SELECT database_name, AVG(blocking_pids) AS blocking_pids_avg
  425. FROM B
  426. GROUP BY database_name
  427. """
  428. }
  429. QUERY_DATABASES = {
  430. DEFAULT: """
  431. SELECT
  432. datname
  433. FROM pg_stat_database
  434. WHERE
  435. has_database_privilege(
  436. (SELECT current_user), datname, 'connect')
  437. AND NOT datname ~* '^template\d'
  438. ORDER BY datname;
  439. """,
  440. }
  441. QUERY_STANDBY = {
  442. DEFAULT: """
  443. SELECT
  444. COALESCE(prs.slot_name, psr.application_name) application_name
  445. FROM pg_stat_replication psr
  446. LEFT OUTER JOIN pg_replication_slots prs on psr.pid = prs.active_pid
  447. WHERE application_name IS NOT NULL;
  448. """,
  449. }
  450. QUERY_REPLICATION_SLOT = {
  451. DEFAULT: """
  452. SELECT slot_name
  453. FROM pg_replication_slots;
  454. """
  455. }
  456. QUERY_STANDBY_DELTA = {
  457. DEFAULT: """
  458. SELECT
  459. COALESCE(prs.slot_name, psr.application_name) application_name,
  460. pg_wal_lsn_diff(
  461. CASE pg_is_in_recovery()
  462. WHEN true THEN pg_last_wal_receive_lsn()
  463. ELSE pg_current_wal_lsn()
  464. END,
  465. sent_lsn) AS sent_delta,
  466. pg_wal_lsn_diff(
  467. CASE pg_is_in_recovery()
  468. WHEN true THEN pg_last_wal_receive_lsn()
  469. ELSE pg_current_wal_lsn()
  470. END,
  471. write_lsn) AS write_delta,
  472. pg_wal_lsn_diff(
  473. CASE pg_is_in_recovery()
  474. WHEN true THEN pg_last_wal_receive_lsn()
  475. ELSE pg_current_wal_lsn()
  476. END,
  477. flush_lsn) AS flush_delta,
  478. pg_wal_lsn_diff(
  479. CASE pg_is_in_recovery()
  480. WHEN true THEN pg_last_wal_receive_lsn()
  481. ELSE pg_current_wal_lsn()
  482. END,
  483. replay_lsn) AS replay_delta
  484. FROM pg_stat_replication psr
  485. LEFT OUTER JOIN pg_replication_slots prs on psr.pid = prs.active_pid
  486. WHERE application_name IS NOT NULL;
  487. """,
  488. V96: """
  489. SELECT
  490. COALESCE(prs.slot_name, psr.application_name) application_name,
  491. pg_xlog_location_diff(
  492. CASE pg_is_in_recovery()
  493. WHEN true THEN pg_last_xlog_receive_location()
  494. ELSE pg_current_xlog_location()
  495. END,
  496. sent_location) AS sent_delta,
  497. pg_xlog_location_diff(
  498. CASE pg_is_in_recovery()
  499. WHEN true THEN pg_last_xlog_receive_location()
  500. ELSE pg_current_xlog_location()
  501. END,
  502. write_location) AS write_delta,
  503. pg_xlog_location_diff(
  504. CASE pg_is_in_recovery()
  505. WHEN true THEN pg_last_xlog_receive_location()
  506. ELSE pg_current_xlog_location()
  507. END,
  508. flush_location) AS flush_delta,
  509. pg_xlog_location_diff(
  510. CASE pg_is_in_recovery()
  511. WHEN true THEN pg_last_xlog_receive_location()
  512. ELSE pg_current_xlog_location()
  513. END,
  514. replay_location) AS replay_delta
  515. FROM pg_stat_replication psr
  516. LEFT OUTER JOIN pg_replication_slots prs on psr.pid = prs.active_pid
  517. WHERE application_name IS NOT NULL;
  518. """,
  519. }
  520. QUERY_STANDBY_LAG = {
  521. DEFAULT: """
  522. SELECT
  523. COALESCE(prs.slot_name, psr.application_name) application_name,
  524. COALESCE(EXTRACT(EPOCH FROM write_lag)::bigint, 0) AS write_lag,
  525. COALESCE(EXTRACT(EPOCH FROM flush_lag)::bigint, 0) AS flush_lag,
  526. COALESCE(EXTRACT(EPOCH FROM replay_lag)::bigint, 0) AS replay_lag
  527. FROM pg_stat_replication psr
  528. LEFT OUTER JOIN pg_replication_slots prs on psr.pid = prs.active_pid
  529. WHERE application_name IS NOT NULL;
  530. """
  531. }
  532. QUERY_REPSLOT_FILES = {
  533. DEFAULT: """
  534. WITH wal_size AS (
  535. SELECT
  536. setting::int AS val
  537. FROM pg_settings
  538. WHERE name = 'wal_segment_size'
  539. )
  540. SELECT
  541. slot_name,
  542. slot_type,
  543. replslot_wal_keep,
  544. count(slot_file) AS replslot_files
  545. FROM
  546. (SELECT
  547. slot.slot_name,
  548. CASE
  549. WHEN slot_file <> 'state' THEN 1
  550. END AS slot_file ,
  551. slot_type,
  552. COALESCE (
  553. floor(
  554. CASE WHEN pg_is_in_recovery()
  555. THEN (
  556. pg_wal_lsn_diff(pg_last_wal_receive_lsn(), slot.restart_lsn)
  557. -- this is needed to account for whole WAL retention and
  558. -- not only size retention
  559. + (pg_wal_lsn_diff(restart_lsn, '0/0') %% s.val)
  560. ) / s.val
  561. ELSE (
  562. pg_wal_lsn_diff(pg_current_wal_lsn(), slot.restart_lsn)
  563. -- this is needed to account for whole WAL retention and
  564. -- not only size retention
  565. + (pg_walfile_name_offset(restart_lsn)).file_offset
  566. ) / s.val
  567. END
  568. ),0) AS replslot_wal_keep
  569. FROM pg_replication_slots slot
  570. LEFT JOIN (
  571. SELECT
  572. slot2.slot_name,
  573. pg_ls_dir('pg_replslot/' || slot2.slot_name) AS slot_file
  574. FROM pg_replication_slots slot2
  575. ) files (slot_name, slot_file)
  576. ON slot.slot_name = files.slot_name
  577. CROSS JOIN wal_size s
  578. ) AS d
  579. GROUP BY
  580. slot_name,
  581. slot_type,
  582. replslot_wal_keep;
  583. """,
  584. V10: """
  585. WITH wal_size AS (
  586. SELECT
  587. current_setting('wal_block_size')::INT * setting::INT AS val
  588. FROM pg_settings
  589. WHERE name = 'wal_segment_size'
  590. )
  591. SELECT
  592. slot_name,
  593. slot_type,
  594. replslot_wal_keep,
  595. count(slot_file) AS replslot_files
  596. FROM
  597. (SELECT
  598. slot.slot_name,
  599. CASE
  600. WHEN slot_file <> 'state' THEN 1
  601. END AS slot_file ,
  602. slot_type,
  603. COALESCE (
  604. floor(
  605. CASE WHEN pg_is_in_recovery()
  606. THEN (
  607. pg_wal_lsn_diff(pg_last_wal_receive_lsn(), slot.restart_lsn)
  608. -- this is needed to account for whole WAL retention and
  609. -- not only size retention
  610. + (pg_wal_lsn_diff(restart_lsn, '0/0') %% s.val)
  611. ) / s.val
  612. ELSE (
  613. pg_wal_lsn_diff(pg_current_wal_lsn(), slot.restart_lsn)
  614. -- this is needed to account for whole WAL retention and
  615. -- not only size retention
  616. + (pg_walfile_name_offset(restart_lsn)).file_offset
  617. ) / s.val
  618. END
  619. ),0) AS replslot_wal_keep
  620. FROM pg_replication_slots slot
  621. LEFT JOIN (
  622. SELECT
  623. slot2.slot_name,
  624. pg_ls_dir('pg_replslot/' || slot2.slot_name) AS slot_file
  625. FROM pg_replication_slots slot2
  626. ) files (slot_name, slot_file)
  627. ON slot.slot_name = files.slot_name
  628. CROSS JOIN wal_size s
  629. ) AS d
  630. GROUP BY
  631. slot_name,
  632. slot_type,
  633. replslot_wal_keep;
  634. """,
  635. }
  636. QUERY_SUPERUSER = {
  637. DEFAULT: """
  638. SELECT current_setting('is_superuser') = 'on' AS is_superuser;
  639. """,
  640. }
  641. QUERY_SHOW_VERSION = {
  642. DEFAULT: """
  643. SHOW server_version_num;
  644. """,
  645. }
  646. QUERY_AUTOVACUUM = {
  647. DEFAULT: """
  648. SELECT
  649. count(*) FILTER (WHERE query LIKE 'autovacuum: ANALYZE%%') AS analyze,
  650. count(*) FILTER (WHERE query LIKE 'autovacuum: VACUUM ANALYZE%%') AS vacuum_analyze,
  651. count(*) FILTER (WHERE query LIKE 'autovacuum: VACUUM%%'
  652. AND query NOT LIKE 'autovacuum: VACUUM ANALYZE%%'
  653. AND query NOT LIKE '%%to prevent wraparound%%') AS vacuum,
  654. count(*) FILTER (WHERE query LIKE '%%to prevent wraparound%%') AS vacuum_freeze,
  655. count(*) FILTER (WHERE query LIKE 'autovacuum: BRIN summarize%%') AS brin_summarize
  656. FROM pg_stat_activity
  657. WHERE query NOT LIKE '%%pg_stat_activity%%';
  658. """,
  659. }
  660. QUERY_FORCED_AUTOVACUUM = {
  661. DEFAULT: """
  662. WITH max_age AS (
  663. SELECT setting AS autovacuum_freeze_max_age
  664. FROM pg_catalog.pg_settings
  665. WHERE name = 'autovacuum_freeze_max_age' )
  666. , per_database_stats AS (
  667. SELECT datname
  668. , m.autovacuum_freeze_max_age::int
  669. , age(d.datfrozenxid) AS oldest_current_xid
  670. FROM pg_catalog.pg_database d
  671. JOIN max_age m ON (true)
  672. WHERE d.datallowconn )
  673. SELECT max(ROUND(100*(oldest_current_xid/autovacuum_freeze_max_age::float))) AS percent_towards_forced_autovacuum
  674. FROM per_database_stats;
  675. """,
  676. }
  677. QUERY_TX_WRAPAROUND = {
  678. DEFAULT: """
  679. WITH max_age AS (
  680. SELECT 2000000000 as max_old_xid
  681. FROM pg_catalog.pg_settings
  682. WHERE name = 'autovacuum_freeze_max_age' )
  683. , per_database_stats AS (
  684. SELECT datname
  685. , m.max_old_xid::int
  686. , age(d.datfrozenxid) AS oldest_current_xid
  687. FROM pg_catalog.pg_database d
  688. JOIN max_age m ON (true)
  689. WHERE d.datallowconn )
  690. SELECT max(oldest_current_xid) AS oldest_current_xid
  691. , max(ROUND(100*(oldest_current_xid/max_old_xid::float))) AS percent_towards_wraparound
  692. FROM per_database_stats;
  693. """,
  694. }
  695. QUERY_DIFF_LSN = {
  696. DEFAULT: """
  697. SELECT
  698. pg_wal_lsn_diff(
  699. CASE pg_is_in_recovery()
  700. WHEN true THEN pg_last_wal_receive_lsn()
  701. ELSE pg_current_wal_lsn()
  702. END,
  703. '0/0') as wal_writes ;
  704. """,
  705. V96: """
  706. SELECT
  707. pg_xlog_location_diff(
  708. CASE pg_is_in_recovery()
  709. WHEN true THEN pg_last_xlog_receive_location()
  710. ELSE pg_current_xlog_location()
  711. END,
  712. '0/0') as wal_writes ;
  713. """,
  714. }
  715. def query_factory(name, version=NO_VERSION):
  716. if name == QUERY_NAME_BACKENDS:
  717. return QUERY_BACKEND[DEFAULT]
  718. elif name == QUERY_NAME_BACKEND_USAGE:
  719. if version < 80200:
  720. return QUERY_BACKEND_USAGE[V72]
  721. if version < 90100:
  722. return QUERY_BACKEND_USAGE[V82]
  723. if version < 90200:
  724. return QUERY_BACKEND_USAGE[V91]
  725. if version < 100000:
  726. return QUERY_BACKEND_USAGE[V92]
  727. elif version < 120000:
  728. return QUERY_BACKEND_USAGE[V10]
  729. return QUERY_BACKEND_USAGE[DEFAULT]
  730. elif name == QUERY_NAME_TABLE_STATS:
  731. return QUERY_TABLE_STATS[DEFAULT]
  732. elif name == QUERY_NAME_INDEX_STATS:
  733. return QUERY_INDEX_STATS[DEFAULT]
  734. elif name == QUERY_NAME_DATABASE:
  735. return QUERY_DATABASE[DEFAULT]
  736. elif name == QUERY_NAME_BGWRITER:
  737. return QUERY_BGWRITER[DEFAULT]
  738. elif name == QUERY_NAME_LOCKS:
  739. return QUERY_LOCKS[DEFAULT]
  740. elif name == QUERY_NAME_BLOCKERS:
  741. if version < 90600:
  742. return QUERY_BLOCKERS[V96]
  743. return QUERY_BLOCKERS[DEFAULT]
  744. elif name == QUERY_NAME_DATABASES:
  745. return QUERY_DATABASES[DEFAULT]
  746. elif name == QUERY_NAME_STANDBY:
  747. return QUERY_STANDBY[DEFAULT]
  748. elif name == QUERY_NAME_REPLICATION_SLOT:
  749. return QUERY_REPLICATION_SLOT[DEFAULT]
  750. elif name == QUERY_NAME_IF_SUPERUSER:
  751. return QUERY_SUPERUSER[DEFAULT]
  752. elif name == QUERY_NAME_SERVER_VERSION:
  753. return QUERY_SHOW_VERSION[DEFAULT]
  754. elif name == QUERY_NAME_AUTOVACUUM:
  755. return QUERY_AUTOVACUUM[DEFAULT]
  756. elif name == QUERY_NAME_FORCED_AUTOVACUUM:
  757. return QUERY_FORCED_AUTOVACUUM[DEFAULT]
  758. elif name == QUERY_NAME_TX_WRAPAROUND:
  759. return QUERY_TX_WRAPAROUND[DEFAULT]
  760. elif name == QUERY_NAME_WAL:
  761. if version < 100000:
  762. return QUERY_WAL[V96]
  763. return QUERY_WAL[DEFAULT]
  764. elif name == QUERY_NAME_ARCHIVE:
  765. if version < 100000:
  766. return QUERY_ARCHIVE[V96]
  767. return QUERY_ARCHIVE[DEFAULT]
  768. elif name == QUERY_NAME_STANDBY_DELTA:
  769. if version < 100000:
  770. return QUERY_STANDBY_DELTA[V96]
  771. return QUERY_STANDBY_DELTA[DEFAULT]
  772. elif name == QUERY_NAME_STANDBY_LAG:
  773. return QUERY_STANDBY_LAG[DEFAULT]
  774. elif name == QUERY_NAME_REPSLOT_FILES:
  775. if version < 110000:
  776. return QUERY_REPSLOT_FILES[V10]
  777. return QUERY_REPSLOT_FILES[DEFAULT]
  778. elif name == QUERY_NAME_DIFF_LSN:
  779. if version < 100000:
  780. return QUERY_DIFF_LSN[V96]
  781. return QUERY_DIFF_LSN[DEFAULT]
  782. raise ValueError('unknown query')
  783. ORDER = [
  784. 'db_stat_temp_files',
  785. 'db_stat_temp_bytes',
  786. 'db_stat_blks',
  787. 'db_stat_tuple_returned',
  788. 'db_stat_tuple_write',
  789. 'db_stat_transactions',
  790. 'db_stat_connections',
  791. 'db_stat_blocking_pids_avg',
  792. 'database_size',
  793. 'backend_process',
  794. 'backend_usage',
  795. 'index_count',
  796. 'index_size',
  797. 'table_count',
  798. 'table_size',
  799. 'wal',
  800. 'wal_writes',
  801. 'archive_wal',
  802. 'checkpointer',
  803. 'stat_bgwriter_alloc',
  804. 'stat_bgwriter_checkpoint',
  805. 'stat_bgwriter_backend',
  806. 'stat_bgwriter_backend_fsync',
  807. 'stat_bgwriter_bgwriter',
  808. 'stat_bgwriter_maxwritten',
  809. 'replication_slot',
  810. 'standby_delta',
  811. 'standby_lag',
  812. 'autovacuum',
  813. 'forced_autovacuum',
  814. 'tx_wraparound_oldest_current_xid',
  815. 'tx_wraparound_percent_towards_wraparound'
  816. ]
  817. CHARTS = {
  818. 'db_stat_transactions': {
  819. 'options': [None, 'Transactions on db', 'transactions/s', 'db statistics', 'postgres.db_stat_transactions',
  820. 'line'],
  821. 'lines': [
  822. ['xact_commit', 'committed', 'incremental'],
  823. ['xact_rollback', 'rolled back', 'incremental']
  824. ]
  825. },
  826. 'db_stat_connections': {
  827. 'options': [None, 'Current connections to db', 'count', 'db statistics', 'postgres.db_stat_connections',
  828. 'line'],
  829. 'lines': [
  830. ['connections', 'connections', 'absolute']
  831. ]
  832. },
  833. 'db_stat_blks': {
  834. 'options': [None, 'Disk blocks reads from db', 'reads/s', 'db statistics', 'postgres.db_stat_blks', 'line'],
  835. 'lines': [
  836. ['blks_read', 'disk', 'incremental'],
  837. ['blks_hit', 'cache', 'incremental']
  838. ]
  839. },
  840. 'db_stat_tuple_returned': {
  841. 'options': [None, 'Tuples returned from db', 'tuples/s', 'db statistics', 'postgres.db_stat_tuple_returned',
  842. 'line'],
  843. 'lines': [
  844. ['tup_returned', 'sequential', 'incremental'],
  845. ['tup_fetched', 'bitmap', 'incremental']
  846. ]
  847. },
  848. 'db_stat_tuple_write': {
  849. 'options': [None, 'Tuples written to db', 'writes/s', 'db statistics', 'postgres.db_stat_tuple_write', 'line'],
  850. 'lines': [
  851. ['tup_inserted', 'inserted', 'incremental'],
  852. ['tup_updated', 'updated', 'incremental'],
  853. ['tup_deleted', 'deleted', 'incremental'],
  854. ['conflicts', 'conflicts', 'incremental']
  855. ]
  856. },
  857. 'db_stat_temp_bytes': {
  858. 'options': [None, 'Temp files written to disk', 'KiB/s', 'db statistics', 'postgres.db_stat_temp_bytes',
  859. 'line'],
  860. 'lines': [
  861. ['temp_bytes', 'size', 'incremental', 1, 1024]
  862. ]
  863. },
  864. 'db_stat_temp_files': {
  865. 'options': [None, 'Temp files written to disk', 'files', 'db statistics', 'postgres.db_stat_temp_files',
  866. 'line'],
  867. 'lines': [
  868. ['temp_files', 'files', 'incremental']
  869. ]
  870. },
  871. 'db_stat_blocking_pids_avg': {
  872. 'options': [None, 'Average number of blocking transactions in db', 'processes', 'db statistics',
  873. 'postgres.db_stat_blocking_pids_avg', 'line'],
  874. 'lines': [
  875. ['blocking_pids_avg', 'blocking', 'absolute']
  876. ]
  877. },
  878. 'database_size': {
  879. 'options': [None, 'Database size', 'MiB', 'database size', 'postgres.db_size', 'stacked'],
  880. 'lines': [
  881. ]
  882. },
  883. 'backend_process': {
  884. 'options': [None, 'Current Backend Processes', 'processes', 'backend processes', 'postgres.backend_process',
  885. 'line'],
  886. 'lines': [
  887. ['backends_active', 'active', 'absolute'],
  888. ['backends_idle', 'idle', 'absolute']
  889. ]
  890. },
  891. 'backend_usage': {
  892. 'options': [None, '% of Connections in use', 'percentage', 'backend processes', 'postgres.backend_usage', 'stacked'],
  893. 'lines': [
  894. ['available', 'available', 'percentage-of-absolute-row'],
  895. ['used', 'used', 'percentage-of-absolute-row']
  896. ]
  897. },
  898. 'index_count': {
  899. 'options': [None, 'Total indexes', 'index', 'indexes', 'postgres.index_count', 'line'],
  900. 'lines': [
  901. ['index_count', 'total', 'absolute']
  902. ]
  903. },
  904. 'index_size': {
  905. 'options': [None, 'Indexes size', 'MiB', 'indexes', 'postgres.index_size', 'line'],
  906. 'lines': [
  907. ['index_size', 'size', 'absolute', 1, 1024 * 1024]
  908. ]
  909. },
  910. 'table_count': {
  911. 'options': [None, 'Total Tables', 'tables', 'tables', 'postgres.table_count', 'line'],
  912. 'lines': [
  913. ['table_count', 'total', 'absolute']
  914. ]
  915. },
  916. 'table_size': {
  917. 'options': [None, 'Tables size', 'MiB', 'tables', 'postgres.table_size', 'line'],
  918. 'lines': [
  919. ['table_size', 'size', 'absolute', 1, 1024 * 1024]
  920. ]
  921. },
  922. 'wal': {
  923. 'options': [None, 'Write-Ahead Logs', 'files', 'wal', 'postgres.wal', 'line'],
  924. 'lines': [
  925. ['written_wal', 'written', 'absolute'],
  926. ['recycled_wal', 'recycled', 'absolute'],
  927. ['total_wal', 'total', 'absolute']
  928. ]
  929. },
  930. 'wal_writes': {
  931. 'options': [None, 'Write-Ahead Logs', 'KiB/s', 'wal_writes', 'postgres.wal_writes', 'line'],
  932. 'lines': [
  933. ['wal_writes', 'writes', 'incremental', 1, 1024]
  934. ]
  935. },
  936. 'archive_wal': {
  937. 'options': [None, 'Archive Write-Ahead Logs', 'files/s', 'archive wal', 'postgres.archive_wal', 'line'],
  938. 'lines': [
  939. ['file_count', 'total', 'incremental'],
  940. ['ready_count', 'ready', 'incremental'],
  941. ['done_count', 'done', 'incremental']
  942. ]
  943. },
  944. 'checkpointer': {
  945. 'options': [None, 'Checkpoints', 'writes', 'checkpointer', 'postgres.checkpointer', 'line'],
  946. 'lines': [
  947. ['checkpoint_scheduled', 'scheduled', 'incremental'],
  948. ['checkpoint_requested', 'requested', 'incremental']
  949. ]
  950. },
  951. 'stat_bgwriter_alloc': {
  952. 'options': [None, 'Buffers allocated', 'KiB/s', 'bgwriter', 'postgres.stat_bgwriter_alloc', 'line'],
  953. 'lines': [
  954. ['buffers_alloc', 'alloc', 'incremental', 1, 1024]
  955. ]
  956. },
  957. 'stat_bgwriter_checkpoint': {
  958. 'options': [None, 'Buffers written during checkpoints', 'KiB/s', 'bgwriter',
  959. 'postgres.stat_bgwriter_checkpoint', 'line'],
  960. 'lines': [
  961. ['buffers_checkpoint', 'checkpoint', 'incremental', 1, 1024]
  962. ]
  963. },
  964. 'stat_bgwriter_backend': {
  965. 'options': [None, 'Buffers written directly by a backend', 'KiB/s', 'bgwriter',
  966. 'postgres.stat_bgwriter_backend', 'line'],
  967. 'lines': [
  968. ['buffers_backend', 'backend', 'incremental', 1, 1024]
  969. ]
  970. },
  971. 'stat_bgwriter_backend_fsync': {
  972. 'options': [None, 'Fsync by backend', 'times', 'bgwriter', 'postgres.stat_bgwriter_backend_fsync', 'line'],
  973. 'lines': [
  974. ['buffers_backend_fsync', 'backend fsync', 'incremental']
  975. ]
  976. },
  977. 'stat_bgwriter_bgwriter': {
  978. 'options': [None, 'Buffers written by the background writer', 'KiB/s', 'bgwriter',
  979. 'postgres.bgwriter_bgwriter', 'line'],
  980. 'lines': [
  981. ['buffers_clean', 'clean', 'incremental', 1, 1024]
  982. ]
  983. },
  984. 'stat_bgwriter_maxwritten': {
  985. 'options': [None, 'Too many buffers written', 'times', 'bgwriter', 'postgres.stat_bgwriter_maxwritten',
  986. 'line'],
  987. 'lines': [
  988. ['maxwritten_clean', 'maxwritten', 'incremental']
  989. ]
  990. },
  991. 'autovacuum': {
  992. 'options': [None, 'Autovacuum workers', 'workers', 'autovacuum', 'postgres.autovacuum', 'line'],
  993. 'lines': [
  994. ['analyze', 'analyze', 'absolute'],
  995. ['vacuum', 'vacuum', 'absolute'],
  996. ['vacuum_analyze', 'vacuum analyze', 'absolute'],
  997. ['vacuum_freeze', 'vacuum freeze', 'absolute'],
  998. ['brin_summarize', 'brin summarize', 'absolute']
  999. ]
  1000. },
  1001. 'forced_autovacuum': {
  1002. 'options': [None, 'Percent towards forced autovacuum', 'percent', 'autovacuum', 'postgres.forced_autovacuum', 'line'],
  1003. 'lines': [
  1004. ['percent_towards_forced_autovacuum', 'percent', 'absolute']
  1005. ]
  1006. },
  1007. 'tx_wraparound_oldest_current_xid': {
  1008. 'options': [None, 'Oldest current XID', 'xid', 'tx_wraparound', 'postgres.tx_wraparound_oldest_current_xid', 'line'],
  1009. 'lines': [
  1010. ['oldest_current_xid', 'xid', 'absolute']
  1011. ]
  1012. },
  1013. 'tx_wraparound_percent_towards_wraparound': {
  1014. 'options': [None, 'Percent towards wraparound', 'percent', 'tx_wraparound', 'postgres.percent_towards_wraparound', 'line'],
  1015. 'lines': [
  1016. ['percent_towards_wraparound', 'percent', 'absolute']
  1017. ]
  1018. },
  1019. 'standby_delta': {
  1020. 'options': [None, 'Standby delta', 'KiB', 'replication delta', 'postgres.standby_delta', 'line'],
  1021. 'lines': [
  1022. ['sent_delta', 'sent delta', 'absolute', 1, 1024],
  1023. ['write_delta', 'write delta', 'absolute', 1, 1024],
  1024. ['flush_delta', 'flush delta', 'absolute', 1, 1024],
  1025. ['replay_delta', 'replay delta', 'absolute', 1, 1024]
  1026. ]
  1027. },
  1028. 'standby_lag': {
  1029. 'options': [None, 'Standby lag', 'seconds', 'replication lag', 'postgres.standby_lag', 'line'],
  1030. 'lines': [
  1031. ['write_lag', 'write lag', 'absolute'],
  1032. ['flush_lag', 'flush lag', 'absolute'],
  1033. ['replay_lag', 'replay lag', 'absolute']
  1034. ]
  1035. },
  1036. 'replication_slot': {
  1037. 'options': [None, 'Replication slot files', 'files', 'replication slot', 'postgres.replication_slot', 'line'],
  1038. 'lines': [
  1039. ['replslot_wal_keep', 'wal keeped', 'absolute'],
  1040. ['replslot_files', 'pg_replslot files', 'absolute']
  1041. ]
  1042. }
  1043. }
  1044. class Service(SimpleService):
  1045. def __init__(self, configuration=None, name=None):
  1046. SimpleService.__init__(self, configuration=configuration, name=name)
  1047. self.order = list(ORDER)
  1048. self.definitions = deepcopy(CHARTS)
  1049. self.do_table_stats = configuration.pop('table_stats', False)
  1050. self.do_index_stats = configuration.pop('index_stats', False)
  1051. self.databases_to_poll = configuration.pop('database_poll', None)
  1052. self.configuration = configuration
  1053. self.conn = None
  1054. self.conn_params = dict()
  1055. self.server_version = None
  1056. self.is_superuser = False
  1057. self.alive = False
  1058. self.databases = list()
  1059. self.secondaries = list()
  1060. self.replication_slots = list()
  1061. self.queries = dict()
  1062. self.data = dict()
  1063. def reconnect(self):
  1064. return self.connect()
  1065. def build_conn_params(self):
  1066. conf = self.configuration
  1067. # connection URIs: https://www.postgresql.org/docs/current/libpq-connect.html#LIBPQ-CONNSTRING
  1068. if conf.get(CONN_PARAM_DSN):
  1069. return {'dsn': conf[CONN_PARAM_DSN]}
  1070. params = {
  1071. CONN_PARAM_HOST: conf.get(CONN_PARAM_HOST),
  1072. CONN_PARAM_PORT: conf.get(CONN_PARAM_PORT, DEFAULT_PORT),
  1073. CONN_PARAM_DATABASE: conf.get(CONN_PARAM_DATABASE),
  1074. CONN_PARAM_USER: conf.get(CONN_PARAM_USER, DEFAULT_USER),
  1075. CONN_PARAM_PASSWORD: conf.get(CONN_PARAM_PASSWORD),
  1076. CONN_PARAM_CONN_TIMEOUT: conf.get(CONN_PARAM_CONN_TIMEOUT, DEFAULT_CONNECT_TIMEOUT),
  1077. 'options': '-c statement_timeout={0}'.format(
  1078. conf.get(CONN_PARAM_STATEMENT_TIMEOUT, DEFAULT_STATEMENT_TIMEOUT)),
  1079. }
  1080. # https://www.postgresql.org/docs/current/libpq-ssl.html
  1081. ssl_params = dict(
  1082. (k, v) for k, v in {
  1083. CONN_PARAM_SSL_MODE: conf.get(CONN_PARAM_SSL_MODE),
  1084. CONN_PARAM_SSL_ROOT_CERT: conf.get(CONN_PARAM_SSL_ROOT_CERT),
  1085. CONN_PARAM_SSL_CRL: conf.get(CONN_PARAM_SSL_CRL),
  1086. CONN_PARAM_SSL_CERT: conf.get(CONN_PARAM_SSL_CERT),
  1087. CONN_PARAM_SSL_KEY: conf.get(CONN_PARAM_SSL_KEY),
  1088. }.items() if v)
  1089. if CONN_PARAM_SSL_MODE not in ssl_params and len(ssl_params) > 0:
  1090. raise ValueError("mandatory 'sslmode' param is missing, please set")
  1091. params.update(ssl_params)
  1092. return params
  1093. def connect(self):
  1094. if self.conn:
  1095. self.conn.close()
  1096. self.conn = None
  1097. try:
  1098. self.conn = psycopg2.connect(**self.conn_params)
  1099. self.conn.set_isolation_level(extensions.ISOLATION_LEVEL_AUTOCOMMIT)
  1100. self.conn.set_session(readonly=True)
  1101. except OperationalError as error:
  1102. self.error(error)
  1103. self.alive = False
  1104. else:
  1105. self.alive = True
  1106. return self.alive
  1107. def check(self):
  1108. if not PSYCOPG2:
  1109. self.error("'python-psycopg2' package is needed to use postgres module")
  1110. return False
  1111. try:
  1112. self.conn_params = self.build_conn_params()
  1113. except ValueError as error:
  1114. self.error('error on creating connection params : {0}', error)
  1115. return False
  1116. if not self.connect():
  1117. self.error('failed to connect to {0}'.format(hide_password(self.conn_params)))
  1118. return False
  1119. try:
  1120. self.check_queries()
  1121. except Exception as error:
  1122. self.error(error)
  1123. return False
  1124. self.populate_queries()
  1125. self.create_dynamic_charts()
  1126. return True
  1127. def get_data(self):
  1128. if not self.alive and not self.reconnect():
  1129. return None
  1130. self.data = dict()
  1131. try:
  1132. cursor = self.conn.cursor(cursor_factory=DictCursor)
  1133. self.data.update(zero_lock_types(self.databases))
  1134. for query, metrics in self.queries.items():
  1135. self.query_stats(cursor, query, metrics)
  1136. except OperationalError:
  1137. self.alive = False
  1138. return None
  1139. cursor.close()
  1140. return self.data
  1141. def query_stats(self, cursor, query, metrics):
  1142. cursor.execute(query, dict(databases=tuple(self.databases)))
  1143. for row in cursor:
  1144. for metric in metrics:
  1145. # databases
  1146. if 'database_name' in row:
  1147. dimension_id = '_'.join([row['database_name'], metric])
  1148. # secondaries
  1149. elif 'application_name' in row:
  1150. dimension_id = '_'.join([row['application_name'], metric])
  1151. # replication slots
  1152. elif 'slot_name' in row:
  1153. dimension_id = '_'.join([row['slot_name'], metric])
  1154. # other
  1155. else:
  1156. dimension_id = metric
  1157. if metric in row:
  1158. if row[metric] is not None:
  1159. self.data[dimension_id] = int(row[metric])
  1160. elif 'locks_count' in row:
  1161. if metric == row['mode']:
  1162. self.data[dimension_id] = row['locks_count']
  1163. def check_queries(self):
  1164. cursor = self.conn.cursor()
  1165. self.server_version = detect_server_version(cursor, query_factory(QUERY_NAME_SERVER_VERSION))
  1166. self.debug('server version: {0}'.format(self.server_version))
  1167. self.is_superuser = check_if_superuser(cursor, query_factory(QUERY_NAME_IF_SUPERUSER))
  1168. self.debug('superuser: {0}'.format(self.is_superuser))
  1169. self.databases = discover(cursor, query_factory(QUERY_NAME_DATABASES))
  1170. self.debug('discovered databases {0}'.format(self.databases))
  1171. if self.databases_to_poll:
  1172. to_poll = self.databases_to_poll.split()
  1173. self.databases = [db for db in self.databases if db in to_poll] or self.databases
  1174. self.secondaries = discover(cursor, query_factory(QUERY_NAME_STANDBY))
  1175. self.debug('discovered secondaries: {0}'.format(self.secondaries))
  1176. if self.server_version >= 94000:
  1177. self.replication_slots = discover(cursor, query_factory(QUERY_NAME_REPLICATION_SLOT))
  1178. self.debug('discovered replication slots: {0}'.format(self.replication_slots))
  1179. cursor.close()
  1180. def populate_queries(self):
  1181. self.queries[query_factory(QUERY_NAME_DATABASE)] = METRICS[QUERY_NAME_DATABASE]
  1182. self.queries[query_factory(QUERY_NAME_BACKENDS)] = METRICS[QUERY_NAME_BACKENDS]
  1183. self.queries[query_factory(QUERY_NAME_BACKEND_USAGE, self.server_version)] = METRICS[QUERY_NAME_BACKEND_USAGE]
  1184. self.queries[query_factory(QUERY_NAME_LOCKS)] = METRICS[QUERY_NAME_LOCKS]
  1185. self.queries[query_factory(QUERY_NAME_BGWRITER)] = METRICS[QUERY_NAME_BGWRITER]
  1186. self.queries[query_factory(QUERY_NAME_DIFF_LSN, self.server_version)] = METRICS[QUERY_NAME_WAL_WRITES]
  1187. self.queries[query_factory(QUERY_NAME_STANDBY_DELTA, self.server_version)] = METRICS[QUERY_NAME_STANDBY_DELTA]
  1188. self.queries[query_factory(QUERY_NAME_BLOCKERS, self.server_version)] = METRICS[QUERY_NAME_BLOCKERS]
  1189. if self.do_index_stats:
  1190. self.queries[query_factory(QUERY_NAME_INDEX_STATS)] = METRICS[QUERY_NAME_INDEX_STATS]
  1191. if self.do_table_stats:
  1192. self.queries[query_factory(QUERY_NAME_TABLE_STATS)] = METRICS[QUERY_NAME_TABLE_STATS]
  1193. if self.is_superuser:
  1194. self.queries[query_factory(QUERY_NAME_ARCHIVE, self.server_version)] = METRICS[QUERY_NAME_ARCHIVE]
  1195. if self.server_version >= 90400:
  1196. self.queries[query_factory(QUERY_NAME_WAL, self.server_version)] = METRICS[QUERY_NAME_WAL]
  1197. if self.server_version >= 100000:
  1198. v = METRICS[QUERY_NAME_REPSLOT_FILES]
  1199. self.queries[query_factory(QUERY_NAME_REPSLOT_FILES, self.server_version)] = v
  1200. if self.server_version >= 90400:
  1201. self.queries[query_factory(QUERY_NAME_AUTOVACUUM)] = METRICS[QUERY_NAME_AUTOVACUUM]
  1202. self.queries[query_factory(QUERY_NAME_FORCED_AUTOVACUUM)] = METRICS[QUERY_NAME_FORCED_AUTOVACUUM]
  1203. self.queries[query_factory(QUERY_NAME_TX_WRAPAROUND)] = METRICS[QUERY_NAME_TX_WRAPAROUND]
  1204. if self.server_version >= 100000:
  1205. self.queries[query_factory(QUERY_NAME_STANDBY_LAG)] = METRICS[QUERY_NAME_STANDBY_LAG]
  1206. def create_dynamic_charts(self):
  1207. for database_name in self.databases[::-1]:
  1208. dim = [
  1209. database_name + '_size',
  1210. database_name,
  1211. 'absolute',
  1212. 1,
  1213. 1024 * 1024,
  1214. ]
  1215. self.definitions['database_size']['lines'].append(dim)
  1216. for chart_name in [name for name in self.order if name.startswith('db_stat')]:
  1217. add_database_stat_chart(
  1218. order=self.order,
  1219. definitions=self.definitions,
  1220. name=chart_name,
  1221. database_name=database_name,
  1222. )
  1223. add_database_lock_chart(
  1224. order=self.order,
  1225. definitions=self.definitions,
  1226. database_name=database_name,
  1227. )
  1228. for application_name in self.secondaries[::-1]:
  1229. add_replication_standby_chart(
  1230. order=self.order,
  1231. definitions=self.definitions,
  1232. name='standby_delta',
  1233. application_name=application_name,
  1234. chart_family='replication delta',
  1235. )
  1236. add_replication_standby_chart(
  1237. order=self.order,
  1238. definitions=self.definitions,
  1239. name='standby_lag',
  1240. application_name=application_name,
  1241. chart_family='replication lag',
  1242. )
  1243. for slot_name in self.replication_slots[::-1]:
  1244. add_replication_slot_chart(
  1245. order=self.order,
  1246. definitions=self.definitions,
  1247. name='replication_slot',
  1248. slot_name=slot_name,
  1249. )
  1250. def discover(cursor, query):
  1251. cursor.execute(query)
  1252. result = list()
  1253. for v in [value[0] for value in cursor]:
  1254. if v not in result:
  1255. result.append(v)
  1256. return result
  1257. def check_if_superuser(cursor, query):
  1258. cursor.execute(query)
  1259. return cursor.fetchone()[0]
  1260. def detect_server_version(cursor, query):
  1261. cursor.execute(query)
  1262. return int(cursor.fetchone()[0])
  1263. def zero_lock_types(databases):
  1264. result = dict()
  1265. for database in databases:
  1266. for lock_type in METRICS['LOCKS']:
  1267. key = '_'.join([database, lock_type])
  1268. result[key] = 0
  1269. return result
  1270. def hide_password(config):
  1271. return dict((k, v if k != 'password' or not v else '*****') for k, v in config.items())
  1272. def add_database_lock_chart(order, definitions, database_name):
  1273. def create_lines(database):
  1274. result = list()
  1275. for lock_type in METRICS['LOCKS']:
  1276. dimension_id = '_'.join([database, lock_type])
  1277. result.append([dimension_id, lock_type, 'absolute'])
  1278. return result
  1279. chart_name = database_name + '_locks'
  1280. order.insert(-1, chart_name)
  1281. definitions[chart_name] = {
  1282. 'options':
  1283. [None, 'Locks on db: ' + database_name, 'locks', 'db ' + database_name, 'postgres.db_locks', 'line'],
  1284. 'lines': create_lines(database_name)
  1285. }
  1286. def add_database_stat_chart(order, definitions, name, database_name):
  1287. def create_lines(database, lines):
  1288. result = list()
  1289. for line in lines:
  1290. new_line = ['_'.join([database, line[0]])] + line[1:]
  1291. result.append(new_line)
  1292. return result
  1293. chart_template = CHARTS[name]
  1294. chart_name = '_'.join([database_name, name])
  1295. order.insert(0, chart_name)
  1296. name, title, units, _, context, chart_type = chart_template['options']
  1297. definitions[chart_name] = {
  1298. 'options': [name, title + ': ' + database_name, units, 'db ' + database_name, context, chart_type],
  1299. 'lines': create_lines(database_name, chart_template['lines'])}
  1300. def add_replication_standby_chart(order, definitions, name, application_name, chart_family):
  1301. def create_lines(standby, lines):
  1302. result = list()
  1303. for line in lines:
  1304. new_line = ['_'.join([standby, line[0]])] + line[1:]
  1305. result.append(new_line)
  1306. return result
  1307. chart_template = CHARTS[name]
  1308. chart_name = '_'.join([application_name, name])
  1309. position = order.index('database_size')
  1310. order.insert(position, chart_name)
  1311. name, title, units, _, context, chart_type = chart_template['options']
  1312. definitions[chart_name] = {
  1313. 'options': [name, title + ': ' + application_name, units, chart_family, context, chart_type],
  1314. 'lines': create_lines(application_name, chart_template['lines'])}
  1315. def add_replication_slot_chart(order, definitions, name, slot_name):
  1316. def create_lines(slot, lines):
  1317. result = list()
  1318. for line in lines:
  1319. new_line = ['_'.join([slot, line[0]])] + line[1:]
  1320. result.append(new_line)
  1321. return result
  1322. chart_template = CHARTS[name]
  1323. chart_name = '_'.join([slot_name, name])
  1324. position = order.index('database_size')
  1325. order.insert(position, chart_name)
  1326. name, title, units, _, context, chart_type = chart_template['options']
  1327. definitions[chart_name] = {
  1328. 'options': [name, title + ': ' + slot_name, units, 'replication slot files', context, chart_type],
  1329. 'lines': create_lines(slot_name, chart_template['lines'])}