|
| 1 | +--- |
| 2 | +slug: /optimize/skipping-indexes/examples |
| 3 | +sidebar_label: 'Data Skipping Indexes - Examples' |
| 4 | +sidebar_position: 2 |
| 5 | +description: 'Consolidated Skip Index Examples' |
| 6 | +title: 'Data Skipping Index Examples' |
| 7 | +doc_type: 'guide' |
| 8 | +--- |
| 9 | + |
| 10 | +# Data Skipping Index Examples {#data-skipping-index-examples} |
| 11 | + |
| 12 | +This page consolidates ClickHouse data skipping index examples, showing how to declare each type, when to use them, and how to verify they're applied. All features work with MergeTree-family tables. |
| 13 | + |
| 14 | +**Index syntax:** `INDEX name expr TYPE type(...) [GRANULARITY N]` |
| 15 | + |
| 16 | +ClickHouse supports five skip index types: |
| 17 | + |
| 18 | +* **minmax** \- Tracks minimum and maximum values in each granule |
| 19 | +* **set(N)** \- Stores up to N distinct values per granule |
| 20 | +* **bloom\_filter(\[false\_positive\_rate\])** \- Probabilistic filter for existence checks |
| 21 | +* **ngrambf\_v1** \- N-gram bloom filter for substring searches |
| 22 | +* **tokenbf\_v1** \- Token-based bloom filter for full-text searches |
| 23 | + |
| 24 | +Each section provides examples with sample data and demonstrates how to verify index usage in query execution. |
| 25 | + |
| 26 | +## MinMax index {#minmax-index} |
| 27 | + |
| 28 | +Best for range predicates on loosely sorted data or columns correlated with ORDER BY. |
| 29 | + |
| 30 | +```sql |
| 31 | +-- Define in CREATE TABLE |
| 32 | +CREATE TABLE events |
| 33 | +( |
| 34 | + ts DateTime, |
| 35 | + user_id UInt64, |
| 36 | + value UInt32, |
| 37 | + INDEX ts_minmax ts TYPE minmax GRANULARITY 1 |
| 38 | +) |
| 39 | +ENGINE=MergeTree |
| 40 | +ORDER BY ts; |
| 41 | + |
| 42 | +-- Or add later and materialize |
| 43 | +ALTER TABLE events ADD INDEX ts_minmax ts TYPE minmax GRANULARITY 1; |
| 44 | +ALTER TABLE events MATERIALIZE INDEX ts_minmax; |
| 45 | + |
| 46 | +-- Query that benefits |
| 47 | +SELECT count() FROM events WHERE ts >= now() - 3600; |
| 48 | + |
| 49 | +-- Verify usage |
| 50 | +EXPLAIN indexes = 1 |
| 51 | +SELECT count() FROM events WHERE ts >= now() - 3600; |
| 52 | +``` |
| 53 | + |
| 54 | +See a [worked example](/best-practices/use-data-skipping-indices-where-appropriate#example) with EXPLAIN and pruning. |
| 55 | + |
| 56 | +## Set index {#set-index} |
| 57 | + |
| 58 | +Use when local (per-block) cardinality is low; not helpful if each block has many distinct values. |
| 59 | + |
| 60 | +```sql |
| 61 | +ALTER TABLE events ADD INDEX user_set user_id TYPE set(100) GRANULARITY 1; |
| 62 | +ALTER TABLE events MATERIALIZE INDEX user_set; |
| 63 | + |
| 64 | +SELECT * FROM events WHERE user_id IN (101, 202); |
| 65 | + |
| 66 | +EXPLAIN indexes = 1 |
| 67 | +SELECT * FROM events WHERE user_id IN (101, 202); |
| 68 | +``` |
| 69 | + |
| 70 | +Creation/materialization workflow and before/after effect are shown in the [basic operation guide](/optimize/skipping-indexes#basic-operation). |
| 71 | + |
| 72 | +## Generic Bloom filter (scalar) {#generic-bloom-filter-scalar} |
| 73 | + |
| 74 | +Good for "needle in a haystack" equality/IN membership. Optional parameter is the false-positive rate (default 0.025). |
| 75 | + |
| 76 | +```sql |
| 77 | +ALTER TABLE events ADD INDEX value_bf value TYPE bloom_filter(0.01) GRANULARITY 3; |
| 78 | +ALTER TABLE events MATERIALIZE INDEX value_bf; |
| 79 | + |
| 80 | +SELECT * FROM events WHERE value IN (7, 42, 99); |
| 81 | + |
| 82 | +EXPLAIN indexes = 1 |
| 83 | +SELECT * FROM events WHERE value IN (7, 42, 99); |
| 84 | +``` |
| 85 | + |
| 86 | +## N-gram Bloom filter (ngrambf\_v1) for substring search {#n-gram-bloom-filter-ngrambf-v1-for-substring-search} |
| 87 | + |
| 88 | +Splits strings into n-grams; works well for LIKE '%...%'. Supports String/FixedString/Map (via mapKeys/mapValues). Tunable size, hash count, seed. See documentation for [N-gram bloom filter](/engines/table-engines/mergetree-family/mergetree#n-gram-bloom-filter). |
| 89 | + |
| 90 | +```sql |
| 91 | +-- Create index for substring search |
| 92 | +ALTER TABLE logs ADD INDEX msg_ngram msg TYPE ngrambf_v1(3, 10000, 3, 7) GRANULARITY 1; |
| 93 | +ALTER TABLE logs MATERIALIZE INDEX msg_ngram; |
| 94 | + |
| 95 | +-- Substring search |
| 96 | +SELECT count() FROM logs WHERE msg LIKE '%timeout%'; |
| 97 | + |
| 98 | +EXPLAIN indexes = 1 |
| 99 | +SELECT count() FROM logs WHERE msg LIKE '%timeout%'; |
| 100 | +``` |
| 101 | + |
| 102 | +[This guide](/use-cases/observability/schema-design#bloom-filters-for-text-search) shows practical examples and when to use token vs ngram. |
| 103 | + |
| 104 | +**Parameter optimization helpers:** |
| 105 | + |
| 106 | +The four ngrambf\_v1 parameters (n-gram size, bitmap size, hash functions, seed) significantly impact performance and memory usage. Use these functions to calculate optimal bitmap size and hash function count based on your expected n-gram volume and desired false positive rate: |
| 107 | + |
| 108 | +```sql |
| 109 | +CREATE FUNCTION bfEstimateFunctions AS |
| 110 | +(total_grams, bits) -> round((bits / total_grams) * log(2)); |
| 111 | + |
| 112 | +CREATE FUNCTION bfEstimateBmSize AS |
| 113 | +(total_grams, p_false) -> ceil((total_grams * log(p_false)) / log(1 / pow(2, log(2)))); |
| 114 | + |
| 115 | +-- Example sizing for 4300 ngrams, p_false = 0.0001 |
| 116 | +SELECT bfEstimateBmSize(4300, 0.0001) / 8 AS size_bytes; -- ~10304 |
| 117 | +SELECT bfEstimateFunctions(4300, bfEstimateBmSize(4300, 0.0001)) AS k; -- ~13 |
| 118 | +``` |
| 119 | + |
| 120 | +See [parameter docs](/engines/table-engines/mergetree-family/mergetree#n-gram-bloom-filter) for complete tuning guidance. |
| 121 | + |
| 122 | +## Token Bloom filter (tokenbf\_v1) for word-based search {#token-bloom-filter-tokenbf-v1-for-word-based-search} |
| 123 | + |
| 124 | +Indexes tokens separated by non-alphanumeric characters; use with hasToken, LIKE word patterns, equals/IN. Supports String/FixedString/Map. See: [Token bloom filter](/engines/table-engines/mergetree-family/mergetree#token-bloom-filter) and [Bloom filter types](/optimize/skipping-indexes#skip-index-types). |
| 125 | + |
| 126 | +```sql |
| 127 | +ALTER TABLE logs ADD INDEX msg_token lower(msg) TYPE tokenbf_v1(10000, 7, 7) GRANULARITY 1; |
| 128 | +ALTER TABLE logs MATERIALIZE INDEX msg_token; |
| 129 | + |
| 130 | +-- Word search (case-insensitive via lower) |
| 131 | +SELECT count() FROM logs WHERE hasToken(lower(msg), 'exception'); |
| 132 | + |
| 133 | +EXPLAIN indexes = 1 |
| 134 | +SELECT count() FROM logs WHERE hasToken(lower(msg), 'exception'); |
| 135 | +``` |
| 136 | + |
| 137 | +See observability examples and guidance on token vs ngram [here](/use-cases/observability/schema-design#bloom-filters-for-text-search). |
| 138 | + |
| 139 | +## Add indexes during CREATE TABLE (multiple examples) {#add-indexes-during-create-table-multiple-examples} |
| 140 | + |
| 141 | +Also supports composite expressions and Map/Tuple/Nested. |
| 142 | + |
| 143 | +```sql |
| 144 | +CREATE TABLE t |
| 145 | +( |
| 146 | + u64 UInt64, |
| 147 | + s String, |
| 148 | + m Map(String, String), |
| 149 | + |
| 150 | + INDEX idx_bf u64 TYPE bloom_filter(0.01) GRANULARITY 3, |
| 151 | + INDEX idx_minmax u64 TYPE minmax GRANULARITY 1, |
| 152 | + INDEX idx_set u64 * length(s) TYPE set(1000) GRANULARITY 4, |
| 153 | + INDEX idx_ngram s TYPE ngrambf_v1(3, 10000, 3, 7) GRANULARITY 1, |
| 154 | + INDEX idx_token mapKeys(m) TYPE tokenbf_v1(10000, 7, 7) GRANULARITY 1 |
| 155 | +) |
| 156 | +ENGINE = MergeTree |
| 157 | +ORDER BY u64; |
| 158 | +``` |
| 159 | + |
| 160 | +## Materializing on existing data and verifying {#materializing-on-existing-data-and-verifying} |
| 161 | + |
| 162 | +Add an index to existing data parts using MATERIALIZE, and inspect pruning with EXPLAIN or trace logs. |
| 163 | + |
| 164 | +```sql |
| 165 | +ALTER TABLE t MATERIALIZE INDEX idx_bf; |
| 166 | + |
| 167 | +EXPLAIN indexes = 1 |
| 168 | +SELECT count() FROM t WHERE u64 IN (123, 456); |
| 169 | + |
| 170 | +-- Optional: detailed pruning info |
| 171 | +SET send_logs_level = 'trace'; |
| 172 | +``` |
| 173 | + |
| 174 | +A [worked minmax example](/best-practices/use-data-skipping-indices-where-appropriate#example) demonstrates EXPLAIN output structure and pruning counts. |
| 175 | + |
| 176 | +## When use and when to avoid {#when-use-and-when-to-avoid} |
| 177 | + |
| 178 | +**Use skip indexes when:** |
| 179 | + |
| 180 | +* Filter values are sparse within data blocks |
| 181 | +* Strong correlation exists with ORDER BY columns or data ingestion patterns group similar values together |
| 182 | +* Performing text searches on large log datasets (ngrambf\_v1/tokenbf\_v1 types) |
| 183 | + |
| 184 | +**Avoid skip indexes when:** |
| 185 | + |
| 186 | +* Most blocks likely contain at least one matching value (blocks will be read regardless) |
| 187 | +* Filtering on high-cardinality columns with no correlation to data ordering |
| 188 | + |
| 189 | +**Important considerations:** If a value appears even once in a data block, ClickHouse must read the entire block. Test indexes with realistic datasets and adjust granularity and type-specific parameters based on actual performance measurements. |
| 190 | + |
| 191 | +## Temporarily ignore or force indexes {#temporarily-ignore-or-force-indexes} |
| 192 | + |
| 193 | +Disable specific indexes by name for individual queries during testing and troubleshooting. Settings also exist to force index usage when needed. See [ignore\_data\_skipping\_indices](/operations/settings/settings#ignore_data_skipping_indices). |
| 194 | + |
| 195 | +```sql |
| 196 | +-- Ignore an index by name |
| 197 | +SELECT * FROM logs |
| 198 | +WHERE hasToken(lower(msg), 'exception') |
| 199 | +SETTINGS ignore_data_skipping_indices = 'msg_token'; |
| 200 | +``` |
| 201 | + |
| 202 | +## Notes and caveats {#notes-and-caveats} |
| 203 | + |
| 204 | +* Only supported on MergeTree-family tables; pruning happens at the granule/block level. |
| 205 | +* Bloom-filter-based indexes are probabilistic (false positives cause extra reads but won't skip valid data). |
| 206 | +* Bloom filters and other skip indexes should be validated with EXPLAIN and tracing; adjust granularity to balance pruning vs. index size. |
| 207 | + |
| 208 | +## Related docs {#related-docs} |
| 209 | +- [Data skipping index guide](/optimize/skipping-indexes) |
| 210 | +- [Best practices guide](/best-practices/use-data-skipping-indices-where-appropriate) |
| 211 | +- [Manipulating data skipping indices](/sql-reference/statements/alter/skipping-index) |
| 212 | +- [System table information](/operations/system-tables/data_skipping_indices) |
0 commit comments