ClickHouse/docs/en/sql-reference/table-functions/mergeTreeIndex.md
2024-02-26 22:47:39 +00:00

84 lines
5.1 KiB
Markdown

---
slug: /en/sql-reference/table-functions/mergeTreeIndex
sidebar_position: 77
sidebar_label: mergeTreeIndex
---
# mergeTreeIndex
Represents the contents of index and marks files of MergeTree tables. It can be used for introspection
``` sql
mergeTreeIndex(database, table, [with_marks = true])
```
**Arguments**
- `database`- The database name to read index and marks from.
- `table`- The table name to read index and marks from.
- `with_marks` - Whether include columns with marks to the result.
**Returned Value**
A table object with columns with values of primary index of source table, columns with values of marks (if enabled) for all possible files in data parts of source table and virtual columns:
- `part_name` - The name of data part.
- `mark_number` - The number of current mark in data part.
- `rows_in_granule` - The number of rows in current granule.
Marks column may contain `(NULL, NULL)` value in case when column is absent in data part or marks for one of its substreams are not written (e.g. in compact parts).
## Usage Example
```sql
CREATE TABLE test_table
(
`id` UInt64,
`n` UInt64,
`arr` Array(UInt64)
)
ENGINE = MergeTree
ORDER BY id
SETTINGS index_granularity = 3, min_bytes_for_wide_part = 0, min_rows_for_wide_part = 8;
INSERT INTO test_table SELECT number, number, range(number % 5) FROM numbers(5);
INSERT INTO test_table SELECT number, number, range(number % 5) FROM numbers(10, 10);
```
```sql
SELECT * FROM mergeTreeIndex(currentDatabase(), test_table, with_marks = true);
```
```text
┌─part_name─┬─mark_number─┬─rows_in_granule─┬─id─┬─id.mark─┬─n.mark──┬─arr.size0.mark─┬─arr.mark─┐
│ all_1_1_0 │ 0 │ 3 │ 0 │ (0,0) │ (42,0) │ (NULL,NULL) │ (84,0) │
│ all_1_1_0 │ 1 │ 2 │ 3 │ (133,0) │ (172,0) │ (NULL,NULL) │ (211,0) │
│ all_1_1_0 │ 2 │ 0 │ 4 │ (271,0) │ (271,0) │ (NULL,NULL) │ (271,0) │
└───────────┴─────────────┴─────────────────┴────┴─────────┴─────────┴────────────────┴──────────┘
┌─part_name─┬─mark_number─┬─rows_in_granule─┬─id─┬─id.mark─┬─n.mark─┬─arr.size0.mark─┬─arr.mark─┐
│ all_2_2_0 │ 0 │ 3 │ 10 │ (0,0) │ (0,0) │ (0,0) │ (0,0) │
│ all_2_2_0 │ 1 │ 3 │ 13 │ (0,24) │ (0,24) │ (0,24) │ (0,24) │
│ all_2_2_0 │ 2 │ 3 │ 16 │ (0,48) │ (0,48) │ (0,48) │ (0,80) │
│ all_2_2_0 │ 3 │ 1 │ 19 │ (0,72) │ (0,72) │ (0,72) │ (0,128) │
│ all_2_2_0 │ 4 │ 0 │ 19 │ (0,80) │ (0,80) │ (0,80) │ (0,160) │
└───────────┴─────────────┴─────────────────┴────┴─────────┴────────┴────────────────┴──────────┘
```
```sql
DESCRIBE mergeTreeIndex(currentDatabase(), test_table, with_marks = true) SETTINGS describe_compact_output = 1;
```
```text
┌─name────────────┬─type─────────────────────────────────────────────────────────────────────────────────────────────┐
│ part_name │ String │
│ mark_number │ UInt64 │
│ rows_in_granule │ UInt64 │
│ id │ UInt64 │
│ id.mark │ Tuple(offset_in_compressed_file Nullable(UInt64), offset_in_decompressed_block Nullable(UInt64)) │
│ n.mark │ Tuple(offset_in_compressed_file Nullable(UInt64), offset_in_decompressed_block Nullable(UInt64)) │
│ arr.size0.mark │ Tuple(offset_in_compressed_file Nullable(UInt64), offset_in_decompressed_block Nullable(UInt64)) │
│ arr.mark │ Tuple(offset_in_compressed_file Nullable(UInt64), offset_in_decompressed_block Nullable(UInt64)) │
└─────────────────┴──────────────────────────────────────────────────────────────────────────────────────────────────┘
```