Grafana Cloud Enterprise Open source

PostgreSQL query editor

The PostgreSQL query editor lets you build and run queries against your data source. For general query editor and data transformation concepts, see Query and transform data.

You can open the PostgreSQL query editor from the Explore page or from a dashboard panel—click the ellipsis in the upper right of the panel and select Edit.

Note

A default database must be configured in the data source settings. If none is set, or it is removed, the data source will not run queries until a database is configured again.

PostgreSQL query editor components

The PostgreSQL query editor has two modes: Builder and Code.

Builder mode helps you build a query using a visual interface. Code mode allows for advanced querying and offers support for complex SQL query writing.

PostgreSQL Builder mode

The following components will help you build a PostgreSQL query:

  • Format - Select the query result format from the drop-down. The default is Table. If you use the Time series format option, one of the columns must be time. Refer to Time series queries for more information.
  • Table - Select a table from the drop-down. Tables correspond to the chosen database.
  • Data operations - Optional Select an aggregation from the drop-down. You can add multiple data operations by clicking the + sign. Click the X sign to remove data operations.
  • Column - Select a column on which to run the aggregation.
  • Alias - Optional Add an alias from the drop-down. You can also add your own alias by typing it in the box and clicking Enter. Remove an alias by clicking the X.
  • Filter - Toggle to add filters.
  • Filter by column value - Optional If you toggle Filter, you can add a column to filter by from the drop-down. To filter on more columns, click the + sign to the right of the condition drop-down. Choose an operator from the drop-down next to the condition. When multiple filters are added, you can add an AND operator to display all true conditions or an OR operator to display any true conditions. Use the second drop-down to choose a filter value. To remove a filter, click the X next to that filter’s drop-down. After selecting a date-type column, you can choose Macros from the operators list and select timeFilter to add the $__timeFilter macro to the query with the selected date column.
  • Group - Toggle to add Group by column.
  • Group by column - Select a column to group by from the drop-down. Click the + sign to group by multiple columns. Click the X to remove a column.
  • Order - Toggle to add an ORDER BY statement.
  • Order by - Select a column to order by from the drop-down. Select ascending (ASC) or descending (DESC) order.
  • Limit - You can add an optional limit on the number of retrieved results. Default is 50.
  • Preview - Toggle for a preview of the SQL query generated by the query builder. Preview is toggled on by default.

PostgreSQL Code mode

To create advanced queries, switch to Code mode by clicking Code in the upper right of the editor window. Code mode supports the auto-completion of tables, columns, SQL keywords, standard SQL functions, Grafana template variables, and Grafana macros. Columns cannot be completed before a table has been specified.

Note

If a table or column name is a reserved word or contains mixed case or special characters, use double quotes in SQL. For example, "user" or "Created At".

Select Table or Time Series as the format. Click the {} in the bottom right to format the query. Click the downward caret to expand the Code mode editor. CTRL/CMD + Return serves as a keyboard shortcut to execute the query.

Warning

Changes made to a query in Code mode will not transfer to Builder mode and will be discarded. You will be prompted to copy your code to the clipboard to save any changes.

Macros

You can add macros to your queries to simplify the syntax and enable dynamic elements, such as date range filters.

PostgreSQL expands macros into native SQL. When the TimescaleDB extension is enabled, $__timeGroup and $__timeGroupAlias use time_bucket() for more efficient grouping.

Macro exampleDescription
$__time(dateColumn)Renames the column to time. Example: dateColumn AS "time". Use for native date/time columns.
$__timeEpoch(dateColumn)Converts to UNIX epoch (seconds) and renames the column to time. Example: extract(epoch from dateColumn) as "time".
$__timeFilter(dateColumn)Replaces the value with a time range filter using the specified column name. Example: dateColumn BETWEEN '2020-07-13T20:19:09.254Z' AND '2020-07-13T21:19:09.254Z'.
$__timeFrom()Replaces the value with the start of the currently active time selection (RFC3339Nano). Example: '2020-07-13T20:19:09.254Z'.
$__timeTo()Replaces the value with the end of the currently active time selection (RFC3339Nano). Example: '2020-07-13T20:19:09.254Z'.
$__timeGroup(dateColumn,'5m')Replaces the value with an expression suitable for use in a GROUP BY clause. Example: floor(extract(epoch from dateColumn)/300)*300. With TimescaleDB: time_bucket('300s', dateColumn).
$__timeGroup(dateColumn,'5m', 0)Same as the $__timeGroup(dateColumn,'5m') macro, but includes a fill parameter to ensure missing points in the series are added by Grafana, using 0 as the default value. This applies only to time series queries.
$__timeGroup(dateColumn,'5m', NULL)Same as the $__timeGroup(dateColumn,'5m', 0) but NULL is used as the value for missing points. This applies only to time series queries.
$__timeGroup(dateColumn,'5m', previous)Same as $__timeGroup(dateColumn,'5m', 0) but uses the previous value in the series as the fill value. If no previous value exists, it uses NULL. This applies only to time series queries.
$__timeGroupAlias(dateColumn,'5m')Same as $__timeGroup but with an added column alias AS "time". With TimescaleDB, uses time_bucket().
$__unixEpochFilter(dateColumn)Replaces the value with a time range filter for columns storing UNIX epoch (seconds). Example: dateColumn >= 1494410783 AND dateColumn <= 1494497183.
$__unixEpochFrom()Replaces the value with the start of the currently active time selection as a UNIX timestamp (seconds). Example: 1494410783.
$__unixEpochTo()Replaces the value with the end of the currently active time selection as a UNIX timestamp (seconds). Example: 1494497183.
$__unixEpochNanoFilter(dateColumn)Replaces the value with a time range filter for columns storing UNIX epoch in nanoseconds. Example: dateColumn >= 1494410783152415214 AND dateColumn <= 1494497183142514872.
$__unixEpochNanoFrom()Replaces the value with the start of the currently active time selection as a nanosecond timestamp. Example: 1494410783152415214.
$__unixEpochNanoTo()Replaces the value with the end of the currently active time selection as a nanosecond timestamp. Example: 1494497183142514872.
$__unixEpochGroup(dateColumn,'5m', [fillmode])Same as $__timeGroup but for columns storing UNIX epoch (seconds). Example: floor((dateColumn)/300)*300. fillMode only works with time series queries.
$__unixEpochGroupAlias(dateColumn,'5m', [fillmode])Same as $__unixEpochGroup but with an added column alias AS "time". fillMode only works with time series queries.

Table SQL queries

If the Format option is set to Table, you can execute virtually any type of SQL query. The Table panel will automatically display the resulting columns and rows from your query.

Table query

You can change or customize the name of a Table panel column by using the SQL keyword AS syntax.

SQL
SELECT
  title as "Title",
  "user".login as "Created By",
  dashboard.created as "Created On"
FROM dashboard
INNER JOIN "user" on "user".id = dashboard.created_by
WHERE $__timeFilter(dashboard.created)

You can use template variables in queries. For example, to filter by a variable named hostname: WHERE hostname IN($hostname).

Time series queries

Set the Format option to Time series to create and run time series queries.

Note

To run a time series query you must include a column named time that returns either a SQL datetime value or a numeric datatype representing the UNIX epoch time in seconds. Additionally, the query results must be sorted by the time column for proper visualization in panels.

The examples in this section refer to the data in the following table:

text
+---------------------+--------------+---------------------+----------+
| time_date_time      | value_double | CreatedAt           | hostname |
+---------------------+--------------+---------------------+----------+
| 2020-01-02 03:05:00 | 3.0          | 2020-01-02 03:05:00 | 10.0.1.1 |
| 2020-01-02 03:06:00 | 4.0          | 2020-01-02 03:06:00 | 10.0.1.2 |
| 2020-01-02 03:10:00 | 6.0          | 2020-01-02 03:10:00 | 10.0.1.1 |
| 2020-01-02 03:11:00 | 7.0          | 2020-01-02 03:11:00 | 10.0.1.2 |
| 2020-01-02 03:20:00 | 5.0          | 2020-01-02 03:20:00 | 10.0.1.2 |
+---------------------+--------------+---------------------+----------+

Time series query results are returned in wide data frame format. In the data frame query result, any column, except for time or string-type columns, transforms into value fields. String columns, on the other hand, become field labels.

Note

For backward compatibility, an exception to this rule applies to queries that return three columns, one of which is a string column named metric. Instead of converting the metric column into field labels, it is used as the field name, while the series name is set to its value. See the following example for reference.

Example with metric column:

SQL
SELECT
  $__timeGroupAlias("time_date_time",'5m'),
  min("value_double"),
  'min' as metric
FROM test_data
WHERE $__timeFilter("time_date_time")
GROUP BY time
ORDER BY time

Data frame result:

text
+---------------------+-----------------+
| Name: time          | Name: min       |
| Labels:             | Labels:         |
| Type: []time.Time   | Type: []float64 |
+---------------------+-----------------+
| 2020-01-02 03:05:00 | 3               |
| 2020-01-02 03:10:00 | 6               |
+---------------------+-----------------+

To customize default series name formatting, refer to Standard options definitions.

Following are time series query examples.

Example with no grouping (raw points):

To return raw time and value points without grouping, use $__time to alias your date/time column as time:

SQL
SELECT
  $__time("time_date_time"),
  "value_double" as value
FROM test_data
WHERE $__timeFilter("time_date_time")
ORDER BY time

Example using the fill parameter in the $__timeGroupAlias macro to convert null values to zero:

SQL
SELECT
  $__timeGroupAlias("CreatedAt",'5m',0),
  sum(value) as value,
  hostname
FROM test_data
WHERE
  $__timeFilter("CreatedAt")
GROUP BY time, hostname
ORDER BY time

Based on the data frame result in the following example, the time series panel will generate two series named value 10.0.1.1 and value 10.0.1.2. To display the series names as 10.0.1.1 and 10.0.1.2, use the Standard options definitions display value ${__field.labels.hostname}.

Data frame result:

text
+---------------------+---------------------------+---------------------------+
| Name: time          | Name: value               | Name: value               |
| Labels:             | Labels: hostname=10.0.1.1 | Labels: hostname=10.0.1.2 |
| Type: []time.Time   | Type: []float64           | Type: []float64           |
+---------------------+---------------------------+---------------------------+
| 2020-01-02 03:05:00 | 3                         | 4                         |
| 2020-01-02 03:10:00 | 6                         | 7                         |
+---------------------+---------------------------+---------------------------+

Example with multiple columns:

SQL
SELECT
  $__timeGroupAlias("time_date_time",'5m'),
  min("value_double") as "min_value",
  max("value_double") as "max_value"
FROM test_data
WHERE $__timeFilter("time_date_time")
GROUP BY time
ORDER BY time

Data frame result:

text
+---------------------+-----------------+-----------------+
| Name: time          | Name: min_value | Name: max_value |
| Labels:             | Labels:         | Labels:         |
| Type: []time.Time   | Type: []float64 | Type: []float64 |
+---------------------+-----------------+-----------------+
| 2020-01-02 03:04:00 | 3               | 4               |
| 2020-01-02 03:05:00 | 6               | 7               |
+---------------------+-----------------+-----------------+

Example with UNIX epoch time column:

When your time column stores UNIX epoch (seconds), use $__timeEpoch to alias it as time and $__unixEpochFilter in the WHERE clause:

SQL
SELECT
  $__timeEpoch(epoch_seconds_column),
  value_column as value
FROM my_table
WHERE $__unixEpochFilter(epoch_seconds_column)
ORDER BY time

For grouped time series with epoch columns, use $__unixEpochGroupAlias and $__unixEpochFilter. See the Macros table for details.

Next steps