README.monitoring_tables 20 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439
  1. -----------------
  2. Monitoring tables
  3. -----------------
  4. Function:
  5. Allow to monitor server-side activity happening inside a particular database.
  6. Concept:
  7. The engine offers a set of so called "virtual" tables that provides the user
  8. with a snapshot of the current activity within the given database. The word
  9. "virtual" means that the table data doesn't exist until explicitly asked for.
  10. However, its metadata is stable and can be retrieved from the schema. Virtual
  11. monitoring tables exist only in ODS 11.1 (and higher) databases, so a
  12. migration via backup/restore is required in order to use this feature.
  13. The key term of the monitoring feature is an activity snapshot. It represents
  14. the current state of the database, consisting of various information about
  15. the database itself, active attachments and users, transactions, prepared and
  16. running statements, etc. A snapshot is created the first time any of the
  17. monitoring tables is being selected from in the given transaction and it's
  18. preserved until the transaction ends, so multiple queries (e.g. master-detail
  19. ones) will always return the consistent view of the data. In other words, the
  20. monitoring tables always behave like a snapshot (aka consistency) transaction,
  21. even if the host transaction has been started with another isolation level.
  22. To refresh the snapshot, the current transaction should be finished and the
  23. monitoring tables should be queried in the new transaction context. Creation
  24. of a snapshot is usually quite fast operation, but some delay should be
  25. expected under high load (especially in the Classic Server).
  26. A valid database connection is required in order to retrieve the monitoring
  27. data. The monitoring tables return information about the attached database
  28. only. If multiple databases are being accessed on the server, each of them
  29. has to be connected to and monitored separately.
  30. System variables CURRENT_CONNECTION and CURRENT_TRANSACTION could be used
  31. to select data about the current (for the caller) connection and transaction
  32. respectively. These variables correspond to the ID columns of the appropriate
  33. monitoring tables.
  34. Security:
  35. Complete database monitoring is available to SYSDBA and a database owner.
  36. Regular users are restricted to the information about their own attachments
  37. only (other attachments are invisible for them).
  38. Author:
  39. Dmitry Yemanov <dimitr at firebirdsql dot org>
  40. Scope:
  41. DSQL and PSQL
  42. MON$DATABASE (connected database)
  43. - MON$DATABASE_NAME (database pathname or alias)
  44. - MON$PAGE_SIZE (page size)
  45. - MON$ODS_MAJOR (major ODS version)
  46. - MON$ODS_MINOR (minor ODS version)
  47. - MON$OLDEST_TRANSACTION (OIT number)
  48. - MON$OLDEST_ACTIVE (OAT number)
  49. - MON$OLDEST_SNAPSHOT (OST number)
  50. - MON$NEXT_TRANSACTION (next transaction number)
  51. - MON$PAGE_BUFFERS (number of pages allocated in the cache)
  52. - MON$SQL_DIALECT (SQL dialect of the database)
  53. - MON$SHUTDOWN_MODE (current shutdown mode)
  54. 0: online
  55. 1: multi-user shutdown
  56. 2: single-user shutdown
  57. 3: full shutdown
  58. - MON$SWEEP_INTERVAL (sweep interval)
  59. - MON$READ_ONLY (read-only flag)
  60. - MON$FORCED_WRITES (sync writes flag)
  61. - MON$RESERVE_SPACE (reserve space flag)
  62. - MON$CREATION_DATE (creation date/time)
  63. - MON$PAGES (number of pages allocated on disk)
  64. - MON$STAT_ID (statistics ID)
  65. - MON$BACKUP_STATE (current physical backup state)
  66. 0: normal
  67. 1: stalled
  68. 2: merge
  69. - MON$CRYPT_STATE (current encryption state)
  70. 0: not encrypted
  71. 1: encrypted
  72. 2: decrypt in progress
  73. 3: encrypt in progress
  74. - MON$CRYPT_PAGE (number of page being encrypted / decrypted)
  75. - MON$OWNER (database owner name)
  76. - MON$SEC_DATABASE (security database)
  77. - MON$GUID (database GUID)
  78. - MON$FILE_ID (unique filesystem-level ID)
  79. - MON$NEXT_ATTACHMENT (next attachment number)
  80. - MON$NEXT_STATEMENT (next statement number)
  81. - MON$REPLICA_MODE (Replica mode of the database)
  82. MON$ATTACHMENTS (connected attachments)
  83. - MON$ATTACHMENT_ID (attachment ID)
  84. - MON$SERVER_PID (server process ID)
  85. - MON$STATE (attachment state)
  86. 0: idle
  87. 1: active
  88. - MON$ATTACHMENT_NAME (connection string)
  89. - MON$USER (user name)
  90. - MON$ROLE (role name)
  91. - MON$REMOTE_PROTOCOL (remote protocol name)
  92. - MON$REMOTE_ADDRESS (remote address)
  93. - MON$REMOTE_PID (remote client process ID)
  94. - MON$REMOTE_PROCESS (remote client process pathname)
  95. - MON$CHARACTER_SET_ID (attachment character set)
  96. - MON$TIMESTAMP (connection date/time)
  97. - MON$GARBAGE_COLLECTION (garbage collection flag)
  98. - MON$STAT_ID (statistics ID)
  99. - MON$CLIENT_VERSION (version of the client library)
  100. - MON$REMOTE_VERSION (version of the remote protocol)
  101. - MON$REMOTE_HOST (remote host name)
  102. - MON$REMOTE_OS_USER (remote OS user name)
  103. - MON$AUTH_METHOD (authentication method used for connection)
  104. - MON$SYSTEM_FLAG (system flag)
  105. 0: user attachment
  106. 1: system attachment
  107. - MON$IDLE_TIMEOUT (connection-level idle timeout)
  108. - MON$IDLE_TIMER (idle timer expiration time)
  109. - MON$STATEMENT_TIMEOUT (statement timeout)
  110. - MON$WIRE_COMPRESSED (wire compression enabled/disabled)
  111. - MON$WIRE_ENCRYPTED (wire encryption enabled/disabled)
  112. - MON$WIRE_CRYPT_PLUGIN (name of wire encryption plugin)
  113. - MON$SESSION_TIMEZONE (time zone of attachment)
  114. - MON$PARALLEL_WORKERS (number of parallel workers that could be used by attachment)
  115. MON$TRANSACTIONS (started transactions)
  116. - MON$TRANSACTION_ID (transaction ID)
  117. - MON$ATTACHMENT_ID (attachment ID)
  118. - MON$STATE (transaction state)
  119. 0: idle
  120. 1: active
  121. - MON$TIMESTAMP (transaction start date/time)
  122. - MON$TOP_TRANSACTION (top transaction)
  123. - MON$OLDEST_TRANSACTION (local OIT number)
  124. - MON$OLDEST_ACTIVE (local OAT number)
  125. - MON$ISOLATION_MODE (isolation mode)
  126. 0: consistency
  127. 1: concurrency
  128. 2: read committed record version
  129. 3: read committed no record version
  130. 4: read committed read consistency
  131. - MON$LOCK_TIMEOUT (lock timeout)
  132. -1: infinite wait
  133. 0: no wait
  134. N: timeout N
  135. - MON$READ_ONLY (read-only flag)
  136. - MON$AUTO_COMMIT (auto-commit flag)
  137. - MON$AUTO_UNDO (auto-undo flag)
  138. - MON$STAT_ID (statistics ID)
  139. MON$STATEMENTS (prepared statements)
  140. - MON$STATEMENT_ID (statement ID)
  141. - MON$ATTACHMENT_ID (attachment ID)
  142. - MON$TRANSACTION_ID (transaction ID)
  143. - MON$STATE (statement state)
  144. 0: idle
  145. 1: active
  146. - MON$TIMESTAMP (statement start date/time)
  147. - MON$SQL_TEXT (statement text, if appropriate)
  148. - MON$STAT_ID (statistics ID)
  149. - MON$EXPLAINED_PLAN (explained query plan)
  150. - MON$STATEMENT_TIMEOUT (statement timeout)
  151. - MON$STATEMENT_TIMER (statement timer expiration time)
  152. - MON$COMPILED_STATEMENT_ID (compiled statement ID)
  153. MON$CALL_STACK (call stack of active PSQL requests)
  154. - MON$CALL_ID (call ID)
  155. - MON$STATEMENT_ID (top-level DSQL statement ID)
  156. - MON$CALLER_ID (caller request ID)
  157. - MON$OBJECT_NAME (PSQL object name)
  158. - MON$OBJECT_TYPE (PSQL object type)
  159. - MON$TIMESTAMP (request start date/time)
  160. - MON$SOURCE_LINE (SQL source line number)
  161. - MON$SOURCE_COLUMN (SQL source column number)
  162. - MON$STAT_ID (statistics ID)
  163. - MON$PACKAGE_NAME (PSQL object package name)
  164. - MON$COMPILED_STATEMENT_ID (compiled statement ID)
  165. MON$IO_STATS (I/O statistics)
  166. - MON$STAT_ID (statistics ID)
  167. - MON$STAT_GROUP (statistics group)
  168. 0: database
  169. 1: attachment
  170. 2: transaction
  171. 3: statement
  172. 4: call
  173. - MON$PAGE_READS (number of page reads)
  174. - MON$PAGE_WRITES (number of page writes)
  175. - MON$PAGE_FETCHES (number of page fetches)
  176. - MON$PAGE_MARKS (number of page marks)
  177. MON$RECORD_STATS (record-level statistics)
  178. - MON$STAT_ID (statistics ID)
  179. - MON$STAT_GROUP (statistics group)
  180. 0: database
  181. 1: attachment
  182. 2: transaction
  183. 3: statement
  184. 4: call
  185. - MON$RECORD_SEQ_READS (number of records read sequentially)
  186. - MON$RECORD_IDX_READS (number of records read via an index)
  187. - MON$RECORD_INSERTS (number of inserted records)
  188. - MON$RECORD_UPDATES (number of updated records)
  189. - MON$RECORD_DELETES (number of deleted records)
  190. - MON$RECORD_BACKOUTS (number of backed out records)
  191. - MON$RECORD_PURGES (number of purged records)
  192. - MON$RECORD_EXPUNGES (number of expunged records)
  193. - MON$RECORD_LOCKS (number of explicit record-level locks)
  194. - MON$RECORD_WAITS (number of waits on conflicting records)
  195. - MON$RECORD_CONFLICTS (number of record-level conflicts reported)
  196. - MON$BACKVERSION_READS (number of backversions read while chasing version chains)
  197. - MON$FRAGMENT_READS (number of fragments read while composing full records)
  198. - MON$RECORD_RPT_READS (number of records read repeatedly, i.e. re-fetched after reading)
  199. - MON$RECORD_IMGC (number of records affected by the intermediate garbage collection)
  200. MON$MEMORY_USAGE (current memory usage)
  201. - MON$STAT_ID (statistics ID)
  202. - MON$STAT_GROUP (statistics group)
  203. 0: database
  204. 1: attachment
  205. 2: transaction
  206. 3: statement
  207. 4: call
  208. - MON$MEMORY_USED (number of bytes currently in use)
  209. - MON$MEMORY_ALLOCATED (number of bytes currently allocated at the OS level)
  210. - MON$MAX_MEMORY_USED (maximum number of bytes used by this object)
  211. - MON$MAX_MEMORY_ALLOCATED (maximum number of bytes allocated from OS by this object)
  212. MON$CONTEXT_VARIABLES (known context variables)
  213. - MON$ATTACHMENT_ID (attachment ID)
  214. - MON$TRANSACTION_ID (transaction ID)
  215. - MON$VARIABLE_NAME (name of context variable)
  216. - MON$VARIABLE_VALUE (value of context variable)
  217. MON$TABLE_STATS (per table record-level statistics)
  218. - MON$STAT_ID (statistics ID)
  219. - MON$STAT_GROUP (statistics group)
  220. 0: database
  221. 1: attachment
  222. 2: transaction
  223. 3: statement
  224. 4: call
  225. - MON$TABLE_NAME (table name)
  226. - MON$RECORD_STAT_ID (record-level statistics ID, refers to MON$RECORD_STATS)
  227. MON$COMPILED_STATEMENTS (compiled statements)
  228. - MON$COMPILED_STATEMENT_ID (compiled statement ID)
  229. - MON$SQL_TEXT (statement text, if appropriate)
  230. - MON$EXPLAINED_PLAN (explained query plan)
  231. - MON$OBJECT_NAME (PSQL object name)
  232. - MON$OBJECT_TYPE (PSQL object type)
  233. - MON$PACKAGE_NAME (PSQL object package name)
  234. - MON$STAT_ID (statistics ID)
  235. Notes:
  236. 1) Textual descriptions of all "state" and "mode" values can be found
  237. in the system table RDB$TYPES
  238. 2) For table MON$ATTACHMENTS:
  239. - columns MON$REMOTE_PID and MON$REMOTE_PROCESS contains non-NULL values
  240. only if the client library has version 2.1 or higher
  241. - column MON$REMOTE_PROCESS can contain a non-pathname value
  242. if an application has specified a custom process name via DPB
  243. 3) For table MON$STATEMENTS:
  244. - column MON$SQL_TEXT contains NULL for GDML statements
  245. - columns MON$TRANSACTION_ID and MON$TIMESTAMP contain valid values
  246. for active statements only
  247. 4) For table MON$CALL_STACK:
  248. - column MON$STATEMENT_ID groups call stacks by the top-level DSQL statement
  249. that initiated the call chain. This ID represents an active statement
  250. record in the table MON$STATEMENTS.
  251. - columns MON$SOURCE_LINE and MON$SOURCE_COLUMN contain line/column information
  252. related to the PSQL statement being currently executed
  253. 5) For table MON$MEMORY_USAGE:
  254. - the "used" values represent high-level memory allocations, i.e. the ones
  255. performed by the engine from its pools. They are useful to investigate unexpected
  256. memory consumptions and find the "guilty" objects (attachments, procedures, etc),
  257. as well as trace memory leaks.
  258. - the "allocated" values represent low-level memory allocations, i.e. the ones
  259. performed by the Firebird memory manager. This means bytes really allocated from OS,
  260. thus allowing to monitor the physical memory consumption. Please note that not every
  261. record has these columns populated with non-zero values. Small allocations don't go
  262. to the OS level, they're redirected to the database memory pool instead. So usually
  263. only MON$DATABASE and memory-bound objects point to non-zero "allocated" values.
  264. - the counter set linked to a record in MON$DATABASE reports the memory shared among
  265. all attachments. In Classic and SuperClassic, these counters are zero meaning no
  266. shared cache in these architectures.
  267. 6) For table MON$CONTEXT_VARIABLES:
  268. - column MON$ATTACHMENT_ID contains a valid ID only for session-level context variables.
  269. Transaction-level ones have this field set to NULL.
  270. - column MON$TRANSACTION_ID contains a valid ID only for transaction-level context variables.
  271. Session-level ones have this field set to NULL.
  272. Example(s):
  273. 1) Retrieve IDs of all CS processes loading CPU at the moment:
  274. SELECT MON$SERVER_PID
  275. FROM MON$ATTACHMENTS
  276. WHERE MON$ATTACHMENT_ID <> CURRENT_CONNECTION
  277. AND MON$STATE = 1
  278. 2) Retrieve information about client applications:
  279. SELECT MON$USER, MON$REMOTE_ADDRESS, MON$REMOTE_PID, MON$TIMESTAMP
  280. FROM MON$ATTACHMENTS
  281. WHERE MON$ATTACHMENT_ID <> CURRENT_CONNECTION
  282. 3) Get isolation level of the current transaction:
  283. SELECT MON$ISOLATION_MODE
  284. FROM MON$TRANSACTIONS
  285. WHERE MON$TRANSACTION_ID = CURRENT_TRANSACTION
  286. 4) Get statements that are currently active:
  287. SELECT ATT.MON$USER, ATT.MON$REMOTE_ADDRESS, STMT.MON$SQL_TEXT, STMT.MON$TIMESTAMP
  288. FROM MON$ATTACHMENTS ATT
  289. JOIN MON$STATEMENTS STMT ON ATT.MON$ATTACHMENT_ID = STMT.MON$ATTACHMENT_ID
  290. WHERE ATT.MON$ATTACHMENT_ID <> CURRENT_CONNECTION
  291. AND STMT.MON$STATE = 1
  292. 5) Retrieve call stacks for all connections:
  293. WITH RECURSIVE
  294. HEAD AS
  295. (
  296. SELECT CALL.MON$STATEMENT_ID, CALL.MON$CALL_ID, CALL.MON$OBJECT_NAME, CALL.MON$OBJECT_TYPE
  297. FROM MON$CALL_STACK CALL
  298. WHERE CALL.MON$CALLER_ID IS NULL
  299. UNION ALL
  300. SELECT CALL.MON$STATEMENT_ID, CALL.MON$CALL_ID, CALL.MON$OBJECT_NAME, CALL.MON$OBJECT_TYPE
  301. FROM MON$CALL_STACK CALL
  302. JOIN HEAD ON CALL.MON$CALLER_ID = HEAD.MON$CALL_ID
  303. )
  304. SELECT MON$ATTACHMENT_ID, MON$OBJECT_NAME, MON$OBJECT_TYPE
  305. FROM HEAD
  306. JOIN MON$STATEMENTS STMT ON STMT.MON$STATEMENT_ID = HEAD.MON$STATEMENT_ID
  307. WHERE STMT.MON$ATTACHMENT_ID <> CURRENT_CONNECTION
  308. 6) Enumerate all session-level context variables for the current connection:
  309. SELECT VAR.MON$VARIABLE_NAME, VAR.MON$VARIABLE_VALUE
  310. FROM MON$CONTEXT_VARIABLES VAR
  311. WHERE VAR.MON$ATTACHMENT_ID = CURRENT_CONNECTION
  312. 7) Report top 10 statements ranked by their memory usage:
  313. SELECT FIRST 10 STMT.MON$ATTACHMENT_ID, STMT.MON$SQL_TEXT, MEM.MON$MEMORY_USED
  314. FROM MON$MEMORY_USAGE MEM
  315. NATURAL JOIN MON$STATEMENTS STMT
  316. ORDER BY MEM.MON$MEMORY_USED DESC
  317. --------------------------------------
  318. Modifications of the monitoring tables
  319. --------------------------------------
  320. Monitoring tables also allow some special administration activities, in particular:
  321. cancelling running statements and terminating client sessions. This is done via deletes
  322. from tables MON$STATEMENTS and MON$ATTACHMENTS respectively. Deletes from other tables,
  323. as well as inserts/updates issued against them, are prohibited.
  324. Notes:
  325. 1) If there are no statements currently running by the client, then the cancellation
  326. attempt becomes a void operation. Once cancelled, the execute/fetch API call returns
  327. the isc_cancelled error code. Any subsequent operations are allowed.
  328. 2) If there are active transactions in the connection being terminated, their activity
  329. is immediately cancelled and they're rolled back. Once terminated, the client session
  330. receives the isc_att_shutdown error code. Subsequent attempts to use this connection
  331. handle will cause network read/write errors.
  332. 3) System attachment can not be cancelled, so engine silently skip system attachments
  333. affected by DELETE FROM MON$ATTACHMENTS statements
  334. Example(s):
  335. 1) Cancel current activity of connection #32:
  336. DELETE FROM MON$STATEMENTS WHERE MON$ATTACHMENT_ID = 32
  337. 2) Disconnect everybody but ourselves:
  338. DELETE FROM MON$ATTACHMENTS WHERE MON$ATTACHMENT_ID <> CURRENT_CONNECTION
  339. --------------
  340. Under the hood
  341. --------------
  342. The monitoring implementation is built around two corner stones: shared memory and
  343. notifications.
  344. All server processes share some region of memory where the current activity information
  345. is stored. This information consists of multiple variable-length items describing the
  346. various activity details. All items that belong to the same process are grouped into a
  347. single cluster, so that they can be processed as a whole.
  348. The monitoring information is not populated/collected in real time. Instead, server
  349. processes write their data into the shared memory only when explicitly asked to. When doing
  350. so, the old clusters are being replaced with newer ones. When the shared memory region is
  351. being read, the reading process scans all the clusters and performs the garbage collection:
  352. clusters that belong to dead processes are removed and the shared memory space is compacted.
  353. Every server process has a flag that indicates its ability to react to someone's monitoring
  354. request as soon as it arrives. When some user connection runs a query against some
  355. monitoring table, the worker process of that connection sends a broadcast notification to
  356. other processes requesting an up-to-date information. Those processes react to this request
  357. by updating their clusters inside the shared memory region and clearing their "ready" flags.
  358. Once the every notified process has finished, the requesting one reads the shared memory
  359. region, filters the necessary tags based on its user permissions, transforms the internal
  360. representation into records and fields and populates the in-memory monitoring tables cache.
  361. Processes that were idle since the last monitoring exchange have their "ready" flag clear,
  362. thus indicating that they have nothing to update in the shared memory. This way they're
  363. excluded from the next roundtrip. As soon as something significant changed inside the
  364. process, the flag is set and this process starts responding to the monitoring requests
  365. again.
  366. The requester holds an exclusive lock while coordinating the write/read operations. This lock
  367. affects the currently active user connections as well as the connections being established.
  368. Multiple simultaneous monitoring requests are serialized.
  369. ----------------------------
  370. Limitations and known issues
  371. ----------------------------
  372. 1) In a heavily loaded system running Classic, monitoring requests may take noticeable time
  373. to execute. In the meantime, other activity (both running statements and new connection
  374. attempts) may be blocked until the monitoring request completes.
  375. Improved since FB v2.1.2.
  376. 2) Monitoring requests may sometimes fail due to the out-of-memory condition, or cause other
  377. worker processes to swap. This is caused by the fact that the every record in MON$STATEMENTS
  378. has a blob MON$SQL_TEXT which is created for the duration of the monitoring transaction.
  379. Prior to FB v2.5, every blob occupied <page size> bytes of memory even if its contents is
  380. in fact smaller. So, with a huge number of prepared statements in the system, it becomes
  381. possible to get this failure.
  382. Another possible reason could be the temporary (very short in practice) growth of the
  383. transaction pool which caches the monitoring data while merging the clusters into a single
  384. fragment.
  385. Improved since FB v2.5.0.