|
| 1 | +# Copyright 2025 The Cockroach Authors |
| 2 | +# |
| 3 | +# Licensed under the Apache License, Version 2.0 (the "License"); |
| 4 | +# you may not use this file except in compliance with the License. |
| 5 | +# You may obtain a copy of the License at |
| 6 | +# |
| 7 | +# http://www.apache.org/licenses/LICENSE-2.0 |
| 8 | +# |
| 9 | +# Unless required by applicable law or agreed to in writing, software |
| 10 | +# distributed under the License is distributed on an "AS IS" BASIS, |
| 11 | +# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. |
| 12 | +# See the License for the specific language governing permissions and |
| 13 | +# limitations under the License. |
| 14 | +# |
| 15 | +# SPDX-License-Identifier: Apache-2.0 |
| 16 | + |
| 17 | +# This query samples local ranges in a node. |
| 18 | +# It chooses ranges that have a replica that shows up as the first replica |
| 19 | +# in the crdb_internal.ranges_no_leases. |
| 20 | +# If the cluster has many ranges (>100K) consider reducing the frequency. |
| 21 | +# The amount of non-live data typically increases slowly, so sampling |
| 22 | +# every few minutes should be acceptable. |
| 23 | +# This query uses internal tables that might change with newer versions. |
| 24 | +# Tested with CRDB v24.2 -> 25.2. |
| 25 | + |
| 26 | +name: table_mvcc_node |
| 27 | +enabled: true |
| 28 | +scope: node |
| 29 | +frequency: 60 |
| 30 | +maxresults: 50 |
| 31 | +labels: [database, table] |
| 32 | +metrics: |
| 33 | + - name : total_bytes |
| 34 | + kind : gauge |
| 35 | + help : total_bytes in all tables. |
| 36 | + - name : garbage_percent |
| 37 | + kind : gauge |
| 38 | + help : garbage_percent. |
| 39 | +query: |
| 40 | + WITH tableinfo AS ( |
| 41 | + SELECT |
| 42 | + range_id, |
| 43 | + ( |
| 44 | + CASE |
| 45 | + WHEN strpos(substring(start_pretty, 8), '/') > 0 |
| 46 | + THEN substring(start_pretty, 8, strpos(substring(start_pretty, 8), '/') - 1) |
| 47 | + ELSE substring(start_pretty, 8) |
| 48 | + END |
| 49 | + )::INT8 AS tableid, |
| 50 | + ( |
| 51 | + (crdb_internal.range_stats(start_key)->>'key_bytes')::INT8 + |
| 52 | + (crdb_internal.range_stats(start_key)->>'val_bytes')::INT8 |
| 53 | + ) AS total_bytes, |
| 54 | + ( |
| 55 | + (crdb_internal.range_stats(start_key)->'live_bytes')::INT8 |
| 56 | + ) AS live_bytes |
| 57 | + FROM |
| 58 | + crdb_internal.ranges_no_leases |
| 59 | + WHERE |
| 60 | + start_pretty::STRING LIKE '/Table/%' AND replicas[1] in (SELECT node_id::INT FROM [SHOW node_id]) |
| 61 | + ), |
| 62 | + result AS ( |
| 63 | + SELECT |
| 64 | + SUM(total_bytes) as total_bytes, |
| 65 | + (100 * (SUM(total_bytes)-SUM(live_bytes)) / SUM(total_bytes))::DECIMAL(5,2) AS garbage_percent, |
| 66 | + dbs.name AS database, |
| 67 | + tbs.name AS table |
| 68 | + FROM |
| 69 | + system.namespace AS tbs, |
| 70 | + system.namespace AS dbs, |
| 71 | + tableinfo |
| 72 | + WHERE |
| 73 | + tableinfo.tableid = tbs.id |
| 74 | + AND tbs."parentID" = dbs.id |
| 75 | + AND tableinfo.total_bytes > 0 |
| 76 | + GROUP BY |
| 77 | + tbs.name, dbs.name |
| 78 | + ) |
| 79 | + SELECT "database", "table", total_bytes, garbage_percent |
| 80 | + FROM result |
| 81 | + WHERE garbage_percent > 0 AND total_bytes > POWER(1024,2) AND "database" != 'system' |
| 82 | + ORDER BY |
| 83 | + garbage_percent DESC |
| 84 | + LIMIT $1; |
0 commit comments