|
| 1 | +--- |
| 2 | +description: This document describes the ClickHouse query editor |
| 3 | +labels: |
| 4 | +products: |
| 5 | + - Grafana Cloud |
| 6 | +keywords: |
| 7 | + - data source |
| 8 | +menuTitle: ClickHouse query editor |
| 9 | +title: ClickHouse query editor |
| 10 | +weight: 30 |
| 11 | +version: 0.1 |
| 12 | +--- |
| 13 | + |
| 14 | +## Building queries |
| 15 | + |
| 16 | +Queries can be built using the raw SQL editor or the query builder. |
| 17 | +Queries can contain macros which simplify syntax and allow for |
| 18 | +dynamic SQL generation. |
| 19 | + |
| 20 | +### Time series |
| 21 | + |
| 22 | +Time series visualization options are selectable after adding a `datetime` |
| 23 | +field type to your query. This field will be used as the timestamp. You can |
| 24 | +select time series visualizations using the visualization options. Grafana |
| 25 | +interprets timestamp rows without explicit time zone as UTC. Any column except |
| 26 | +`time` is treated as a value column. |
| 27 | + |
| 28 | +#### Multi-line time series |
| 29 | + |
| 30 | +To create multi-line time series, the query must return at least 3 fields in |
| 31 | +the following order: |
| 32 | + |
| 33 | +- field 1: `datetime` field with an alias of `time` |
| 34 | +- field 2: value to group by |
| 35 | +- field 3+: the metric values |
| 36 | + |
| 37 | +For example: |
| 38 | + |
| 39 | +```sql |
| 40 | +SELECT log_time AS time, machine_group, avg(disk_free) AS avg_disk_free |
| 41 | +FROM mgbench.logs1 |
| 42 | +GROUP BY machine_group, log_time |
| 43 | +ORDER BY log_time |
| 44 | +``` |
| 45 | + |
| 46 | +### Tables |
| 47 | + |
| 48 | +Table visualizations will always be available for any valid ClickHouse query. |
| 49 | + |
| 50 | +### Visualizing logs with the Logs Panel |
| 51 | + |
| 52 | +To use the Logs panel your query must return a timestamp and string values. To default to the logs visualization in Explore mode, set the timestamp alias to _log_time_. |
| 53 | + |
| 54 | +For example: |
| 55 | + |
| 56 | +```sql |
| 57 | +SELECT log_time AS log_time, machine_group, toString(avg(disk_free)) AS avg_disk_free |
| 58 | +FROM logs1 |
| 59 | +GROUP BY machine_group, log_time |
| 60 | +ORDER BY log_time |
| 61 | +``` |
| 62 | + |
| 63 | +To force rendering as logs, in absence of a `log_time` column, set the Format to `Logs` (available from 2.2.0). |
| 64 | + |
| 65 | +### Visualizing traces with the Traces Panel |
| 66 | + |
| 67 | +Ensure your data meets the [requirements of the traces panel](https://grafana.com/docs/grafana/latest/explore/trace-integration/#data-api). This applies if using the visualization or Explore view. |
| 68 | + |
| 69 | +Set the Format to `Trace` when constructing the query (available from 2.2.0). |
| 70 | + |
| 71 | +If using the [Open Telemetry Collector and ClickHouse exporter](https://github.com/open-telemetry/opentelemetry-collector-contrib/tree/main/exporter/clickhouseexporter), the following query produces the required column names (these are case sensitive): |
| 72 | + |
| 73 | +```sql |
| 74 | +SELECT |
| 75 | + TraceId AS traceID, |
| 76 | + SpanId AS spanID, |
| 77 | + SpanName AS operationName, |
| 78 | + ParentSpanId AS parentSpanID, |
| 79 | + ServiceName AS serviceName, |
| 80 | + Duration / 1000000 AS duration, |
| 81 | + Timestamp AS startTime, |
| 82 | + arrayMap(key -> map('key', key, 'value', SpanAttributes[key]), mapKeys(SpanAttributes)) AS tags, |
| 83 | + arrayMap(key -> map('key', key, 'value', ResourceAttributes[key]), mapKeys(ResourceAttributes)) AS serviceTags, |
| 84 | + if(StatusCode IN ('Error', 'STATUS_CODE_ERROR'), 2, 0) AS statusCode |
| 85 | +FROM otel.otel_traces |
| 86 | +WHERE TraceId = '61d489320c01243966700e172ab37081' |
| 87 | +ORDER BY startTime ASC |
| 88 | +``` |
| 89 | + |
| 90 | +### Macros |
| 91 | + |
| 92 | +To simplify syntax and to allow for dynamic parts, like date range filters, the query can contain macros. |
| 93 | + |
| 94 | +Here is an example of a query with a macro that will use Grafana's time filter: |
| 95 | + |
| 96 | +```sql |
| 97 | +SELECT date_time, data_stuff |
| 98 | +FROM test_data |
| 99 | +WHERE $__timeFilter(date_time) |
| 100 | +``` |
| 101 | + |
| 102 | +| Macro | Description | Output example | |
| 103 | +| ---------------------------------------------- | ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- | ----------------------------------------------------------------------------------------------------- | |
| 104 | +| _$\_\_dateFilter(columnName)_ | Replaced by a conditional that filters the data (using the provided column) based on the date range of the panel | `date >= toDate('2022-10-21') AND date <= toDate('2022-10-23')` | |
| 105 | +| _$\_\_timeFilter(columnName)_ | Replaced by a conditional that filters the data (using the provided column) based on the time range of the panel in seconds | `time >= toDateTime(1415792726) AND time <= toDateTime(1447328726)` | |
| 106 | +| _$\_\_timeFilter_ms(columnName)_ | Replaced by a conditional that filters the data (using the provided column) based on the time range of the panel in milliseconds | `time >= fromUnixTimestamp64Milli(1415792726123) AND time <= fromUnixTimestamp64Milli(1447328726456)` | |
| 107 | +| _$\_\_dateTimeFilter(dateColumn, timeColumn)_ | Shorthand that combines $**dateFilter() AND $**timeFilter() using separate Date and DateTime columns. | `$__dateFilter(dateColumn) AND $__timeFilter(timeColumn)` | |
| 108 | +| _$\_\_fromTime_ | Replaced by the starting time of the range of the panel casted to `DateTime` | `toDateTime(1415792726)` | |
| 109 | +| _$\_\_toTime_ | Replaced by the ending time of the range of the panel casted to `DateTime` | `toDateTime(1447328726)` | |
| 110 | +| _$\_\_fromTime_ms_ | Replaced by the starting time of the range of the panel casted to `DateTime64(3)` | `fromUnixTimestamp64Milli(1415792726123)` | |
| 111 | +| _$\_\_toTime_ms_ | Replaced by the ending time of the range of the panel casted to `DateTime64(3)` | `fromUnixTimestamp64Milli(1447328726456)` | |
| 112 | +| _$\_\_interval_s_ | Replaced by the interval in seconds | `20` | |
| 113 | +| _$\_\_timeInterval(columnName)_ | Replaced by a function calculating the interval based on window size in seconds, useful when grouping | `toStartOfInterval(toDateTime(column), INTERVAL 20 second)` | |
| 114 | +| _$\_\_timeInterval_ms(columnName)_ | Replaced by a function calculating the interval based on window size in milliseconds, useful when grouping | `toStartOfInterval(toDateTime64(column, 3), INTERVAL 20 millisecond)` | |
| 115 | +| _$\_\_conditionalAll(condition, $templateVar)_ | Replaced by the first parameter when the template variable in the second parameter does not select every value. Replaced by the 1=1 when the template variable selects every value. | `condition` or `1=1` | |
| 116 | + |
| 117 | +The plugin also supports notation using braces {}. Use this notation when queries are needed inside parameters. |
0 commit comments