Debugging memory issues
When encountering memory issues or a memory leak, knowing what queries and resources are consuming a significant amount of memory is helpful. Below are queries that can help debug and find which queries, databases, and tables can be optimized:
List currently running processes by peak memory usage
SELECT
initial_query_id,
query,
elapsed,
formatReadableSize(memory_usage),
formatReadableSize(peak_memory_usage),
FROM system.processes
ORDER BY peak_memory_usage DESC
LIMIT 100;
List metrics for memory usage
SELECT
metric, description, formatReadableSize(value) size
FROM
system.asynchronous_metrics
WHERE
metric like '%Cach%'
or metric like '%Mem%'
order by
value desc;
List tables by current memory usage
SELECT
database,
name,
formatReadableSize(total_bytes)
FROM system.tables
WHERE engine IN ('Memory','Set','Join');
Output total memory used by merges
SELECT formatReadableSize(sum(memory_usage)) FROM system.merges;
Output total memory used by currently running processes
SELECT formatReadableSize(sum(memory_usage)) FROM system.processes;
Output total memory used by dictionaries
SELECT formatReadableSize(sum(bytes_allocated)) FROM system.dictionaries;
Output total memory used by primary keys
SELECT
sumIf(data_uncompressed_bytes, part_type = 'InMemory') as memory_parts,
formatReadableSize(sum(primary_key_bytes_in_memory)) AS primary_key_bytes_in_memory,
formatReadableSize(sum(primary_key_bytes_in_memory_allocated)) AS primary_key_bytes_in_memory_allocated
FROM system.parts;