Query Monitoring

You are viewing an old version of this article. View the current version here.

Active SQL Statement

show processlist

MariaDB show processlist command may be used to see list of active queries

MariaDB [test]> show processlist;
+----+------+-----------+-------+---------+------+-------+--------------+
| Id | User | Host | db | Command | Time | State | Info |
+----+------+-----------+-------+---------+------+-------+--------------+
| 73 | root | localhost | ssb10 | Query | 0 | NULL | show processlist
+----+------+-----------+-------+---------+------+-------+--------------+
1 row in set (0.01 sec)

getActiveSQLStatements

getActiveSQLStatements is a mcsdmin command that shows what SQL is currently being executed on the database:

mcsadmin> getActiveSQLStatements
getactivesqlstatements Wed Oct 7 08:38:32 2015
Get List of Active SQL Statements
=================================
Start Time    Time (hh:mm:ss) Session ID SQL Statement
---------------- ---------------- -------------------- ------------------------------------------------------------
Oct 7 08:38:30    00:00:03       73 select c_name,sum(lo_revenue) from customer, lineorder where lo_custkey = c_custkey and c_custkey = 6 group by c_name

Single Query Statistics

calgetstats

This SQL stored function provides statistics about resources used on UM node, PM node, and network by the last run query Example:

MariaDB [wide]> select count(*) from wide2;
+----------+                                       
| count(*) |
+----------+
|  5000000 |
+----------+
1 row in set (0.22 sec)

MariaDB [wide]> select calgetstats();
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| calgetstats()                                                                                                                                                                                     |
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Query Stats: MaxMemPct-0; NumTempFiles-0; TempFileSpace-0B; ApproxPhyI/O-1931; CacheI/O-2446; BlocksTouched-2443; PartitionBlocksEliminated-0; MsgBytesIn-73KB; MsgBytesOut-1KB; Mode-Distributed |
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
1 row in set (0.01 sec)

The output contains information on:

  • MaxMemPct - Peak memory utilization on the User Module, likely in support of a large (User Module) based hash join operation.
  • NumTempFiles - Report on any temporary files created in support of query operations larger than available memory, typically for unusual join operations where the smaller table join cardinality exceeds some configurable threshold.
  • TempFileSpace - Report on space used by temporary files created in support of query operations larger than available memory, typically for unusual join operations where the smaller table join cardinality exceeds some configurable threshold.
  • PhyI/O - Number of 8k blocks read from disk, SSD, or other persistent storage.
  • CacheI/O - Approximate number of 8k blocks processed in memory, adjusted down by the number of discrete PhyI/O calls required.
  • BlocksTouched - Approximate number of 8k blocks processed in memory.
  • PartitionBlocksEliminated - The number of block touches eliminated via the Extent Map elimination behavior.
  • MsgBytesIn, MsgByteOut - Message bytes in MB sent between nodes in support of the query.

Query Plan

While the MariaDB Server's EXPLAIN utility can be used to look at query plan - It is somewhat less helpful for ColumnStore tables as ColumnStore does not use indexes or make use of MariaDB I/O functionality. The excution plan for a query on columnstore table is made up of multiple steps. Each step in query plan performs a set of operations that are issued from the User Module to the set of Performance Modules in support of a given step in a query.

  • Full Column Scan - an operation that scans each entry in a column using all available threads on the Performance Modules. Speed of operation is generally related to the size of the data type and the total number of rows in the column. The closest analogy for a traditional system is an index scan operation.
  • Partitioned Column Scan - an operation that uses the Extent Map to identify that certain portions of the column do not contain any matching values for a given set of filters. The closest analogy for a traditional row based dbms is a partitioned index scan, or partitioned table scan operation.
  • Column lookup by row offset - once the set of matching filters have been applied and the minimal set of rows have been identified, additional blocks are requested using a calculation that determines exactly which block is required. The closest analogy for a traditional system is a lookup by rowid.

These operations are automatically executed together in order to execute appropriate filters and column lookup by row offset.

Viewing ColumnStore Query Plan

In MariaDB ColumnStore there is a set of SQL tracing stored functions provided to see the distributed query execution plan between UM and PM

The basic steps to using these SQL tracing stored functions are:

  1. Start the trace for the particular session
  2. Execute the SQL statement in question
  3. Review the trace collected for the statement As an example, the following session starts a trace, issues a query against a 6 million row fact table and 300,000 row dimension table, and then reviews the output from the trace:
MariaDB [test] > select calsettrace(1);
+----------------+
| calsettrace(1) |
+----------------+
| 1              |
+----------------+
1 row in set (0.04 sec)
MariaDB [test] > select c_name, sum(lo_revenue)
-> from customer, lineorder
-> where lo_custkey = c_custkey and
-> c_custkey = 5
-> group by c_name;
+--------------------+-----------------+
| c_name | sum(lo_revenue) |
+--------------------+-----------------+
| Customer#000000005 | 552483078.00 |
+--------------------+-----------------+
1 row in set, 0 warning (1.23 sec)
MariaDB [test] > select calgettrace();
+-----------------------------------------------------------------------------------+
| calgettrace()
|+------------------------------------------------------------------------------------+
| 
Desc Mode Table TableOID ReferencedOIDs PIO LIO PBE Elapsed Rows
BPS  PM   customer  3215  (3328,3336)        0   150 0   0.017   1  
BPS  PM   lineorder 3278  (3281,3291)    4096   29808 0  0 0.766 63  
HJS  PM   lineorder  3278   -        -         -   -   0.000 -   -  
ADS  UM       -          -        -        -   -    -   0.724    -   
|
+-----------------------------------------------------------------------------------------+
1 row in set (0.02 sec)

Query History

Comments

Comments loading...
Content reproduced on this site is the property of its respective owners, and this content is not reviewed in advance by MariaDB. The views, information and opinions expressed by this content do not necessarily represent those of MariaDB or any other party.