grafana/docs/sources/features/datasources/postgres.md

187 lines
7.8 KiB
Markdown
Raw Normal View History

Postgres Data Source (#9475) * add postgresql datasource * add rest of files for postgres datasource * fix timeseries query, remove unused code * consistent naming, refactoring * s/mysql/postgres/ * s/mysql/postgres/ * couple more tests * tests for more datatypes * fix macros for postgres * add __timeSec macro * add frontend for postgres datasource * adjust documentation * fix formatting * add proper plugin description * merge editor changes from mysql * port changes from mysql datasource * set proper defaultQuery for postgres * add time_sec to timeseries query accept int for value for timeseries query * revert allowing time_sec and handle int or float values as unix timestamp for "time" column * fix tslint error * handle decimal values in timeseries query * allow setting sslmode for postgres datasource * use type switch for handling data types * fix value for timeseries query * refactor timeseries queries to make them more flexible * remove debug statement from inner loop in type conversion * use plain for loop in getTypedRowData * fix timeseries queries * adjust postgres datasource to tsdb refactoring * adjust postgres datasource to frontend changes * update lib/pq to latest version * move type conversion to getTypedRowData * handle address types cidr, inet and macaddr * adjust response parser and docs for annotations * convert unknown types to string * add documentation for postgres datasource * add another example query with metric column * set more helpful default query * update help text in query editor * handle NULL in value column of timeseries query * add __timeGroup macro * add test for __timeGroup macro * document __timeGroup and set proper default query for annotations * fix typos in docs * add postgres to list of datasources * add postgres to builtInPlugins * mysql: refactoring as prep for merging postgres Refactors out the initialization of the xorm engine and the query logic for an sql data source. * mysql: rename refactoring + test update * postgres:refactor to use SqlEngine(same as mysql) Refactored to use a common base class with the MySql data source. Other changes from the original PR: - Changed time column to be time_sec to allow other time units in the future and to be the same as MySQL - Changed integration test to test the main Query method rather than the private transformToTable method - Changed the __timeSec macro name to __timeEpoch - Renamed PostgresExecutor to PostgresQueryEndpoint Fixes #9209 (the original PR) * postgres: encrypt password on config page With some other cosmetic changes to the config page: - placeholder texts - reset button for the password after it has been encrypted. - default value for the sslmode field. * postgres: change back col name to time from time_sec * postgres mysql: remove annotation title Title has been removed from annotations * postgres: fix images for docs page * postgres mysql: fix specs
2017-10-10 08:19:14 -05:00
+++
title = "Using PostgreSQL in Grafana"
description = "Guide for using PostgreSQL in Grafana"
keywords = ["grafana", "postgresql", "guide"]
type = "docs"
[menu.docs]
name = "PostgreSQL"
parent = "datasources"
weight = 7
+++
# Using PostgreSQL in Grafana
Grafana ships with a built-in PostgreSQL data source plugin that allows you to query and visualize data from a PostgreSQL compatible database.
## Adding the data source
1. Open the side menu by clicking the Grafana icon in the top header.
2. In the side menu under the `Dashboards` link you should find a link named `Data Sources`.
3. Click the `+ Add data source` button in the top header.
4. Select *PostgreSQL* from the *Type* dropdown.
### Database User Permissions (Important!)
The database user you specify when you add the data source should only be granted SELECT permissions on
the specified database & tables you want to query. Grafana does not validate that the query is safe. The query
could include any SQL statement. For example, statements like `DELETE FROM user;` and `DROP TABLE user;` would be
executed. To protect against this we **Highly** recommmend you create a specific postgresql user with restricted permissions.
Example:
```sql
CREATE USER grafanareader WITH PASSWORD 'password';
GRANT USAGE ON SCHEMA schema TO grafanareader;
GRANT SELECT ON schema.table TO grafanareader;
```
Make sure the user does not get any unwanted privileges from the public role.
## Macros
To simplify syntax and to allow for dynamic parts, like date range filters, the query can contain macros.
Macro example | Description
------------ | -------------
*$__time(dateColumn)* | Will be replaced by an expression to rename the column to `time`. For example, *dateColumn as time*
*$__timeSec(dateColumn)* | Will be replaced by an expression to rename the column to `time` and converting the value to unix timestamp. For example, *extract(epoch from dateColumn) as time*
*$__timeFilter(dateColumn)* | Will be replaced by a time range filter using the specified column name. For example, *dateColumn > to_timestamp(1494410783) AND dateColumn < to_timestamp(1494497183)*
*$__timeFrom()* | Will be replaced by the start of the currently active time selection. For example, *to_timestamp(1494410783)*
*$__timeTo()* | Will be replaced by the end of the currently active time selection. For example, *to_timestamp(1494497183)*
*$__timeGroup(dateColumn,'5m')* | Will be replaced by an expression usable in GROUP BY clause. For example, *(extract(epoch from "dateColumn")/extract(epoch from '5m'::interval))::int*extract(epoch from '5m'::interval)*
Postgres Data Source (#9475) * add postgresql datasource * add rest of files for postgres datasource * fix timeseries query, remove unused code * consistent naming, refactoring * s/mysql/postgres/ * s/mysql/postgres/ * couple more tests * tests for more datatypes * fix macros for postgres * add __timeSec macro * add frontend for postgres datasource * adjust documentation * fix formatting * add proper plugin description * merge editor changes from mysql * port changes from mysql datasource * set proper defaultQuery for postgres * add time_sec to timeseries query accept int for value for timeseries query * revert allowing time_sec and handle int or float values as unix timestamp for "time" column * fix tslint error * handle decimal values in timeseries query * allow setting sslmode for postgres datasource * use type switch for handling data types * fix value for timeseries query * refactor timeseries queries to make them more flexible * remove debug statement from inner loop in type conversion * use plain for loop in getTypedRowData * fix timeseries queries * adjust postgres datasource to tsdb refactoring * adjust postgres datasource to frontend changes * update lib/pq to latest version * move type conversion to getTypedRowData * handle address types cidr, inet and macaddr * adjust response parser and docs for annotations * convert unknown types to string * add documentation for postgres datasource * add another example query with metric column * set more helpful default query * update help text in query editor * handle NULL in value column of timeseries query * add __timeGroup macro * add test for __timeGroup macro * document __timeGroup and set proper default query for annotations * fix typos in docs * add postgres to list of datasources * add postgres to builtInPlugins * mysql: refactoring as prep for merging postgres Refactors out the initialization of the xorm engine and the query logic for an sql data source. * mysql: rename refactoring + test update * postgres:refactor to use SqlEngine(same as mysql) Refactored to use a common base class with the MySql data source. Other changes from the original PR: - Changed time column to be time_sec to allow other time units in the future and to be the same as MySQL - Changed integration test to test the main Query method rather than the private transformToTable method - Changed the __timeSec macro name to __timeEpoch - Renamed PostgresExecutor to PostgresQueryEndpoint Fixes #9209 (the original PR) * postgres: encrypt password on config page With some other cosmetic changes to the config page: - placeholder texts - reset button for the password after it has been encrypted. - default value for the sslmode field. * postgres: change back col name to time from time_sec * postgres mysql: remove annotation title Title has been removed from annotations * postgres: fix images for docs page * postgres mysql: fix specs
2017-10-10 08:19:14 -05:00
*$__unixEpochFilter(dateColumn)* | Will be replaced by a time range filter using the specified column name with times represented as unix timestamp. For example, *dateColumn > 1494410783 AND dateColumn < 1494497183*
*$__unixEpochFrom()* | Will be replaced by the start of the currently active time selection as unix timestamp. For example, *1494410783*
*$__unixEpochTo()* | Will be replaced by the end of the currently active time selection as unix timestamp. For example, *1494497183*
We plan to add many more macros. If you have suggestions for what macros you would like to see, please [open an issue](https://github.com/grafana/grafana) in our GitHub repo.
The query editor has a link named `Generated SQL` that shows up after a query as been executed, while in panel edit mode. Click on it and it will expand and show the raw interpolated SQL string that was executed.
## Table queries
If the `Format as` query option is set to `Table` then you can basically do any type of SQL query. The table panel will automatically show the results of whatever columns & rows your query returns.
Query editor with example query:
![](/img/docs/v46/postgres_table_query.png)
The query:
```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 control the name of the Table panel columns by using regular `as ` SQL column selection syntax.
The resulting table panel:
![](/img/docs/v46/postgres_table.png)
### Time series queries
If you set `Format as` to `Time series`, for use in Graph panel for example, then the query must return a column named `time` that returns either a sql datetime or any numeric datatype representing unix epoch in seconds.
Any column except `time` and `metric` is treated as a value column.
You may return a column named `metric` that is used as metric name for the value column.
Example with `metric` column
```sql
SELECT
$__timeGroup(time_date_time,'5m') as time,
Postgres Data Source (#9475) * add postgresql datasource * add rest of files for postgres datasource * fix timeseries query, remove unused code * consistent naming, refactoring * s/mysql/postgres/ * s/mysql/postgres/ * couple more tests * tests for more datatypes * fix macros for postgres * add __timeSec macro * add frontend for postgres datasource * adjust documentation * fix formatting * add proper plugin description * merge editor changes from mysql * port changes from mysql datasource * set proper defaultQuery for postgres * add time_sec to timeseries query accept int for value for timeseries query * revert allowing time_sec and handle int or float values as unix timestamp for "time" column * fix tslint error * handle decimal values in timeseries query * allow setting sslmode for postgres datasource * use type switch for handling data types * fix value for timeseries query * refactor timeseries queries to make them more flexible * remove debug statement from inner loop in type conversion * use plain for loop in getTypedRowData * fix timeseries queries * adjust postgres datasource to tsdb refactoring * adjust postgres datasource to frontend changes * update lib/pq to latest version * move type conversion to getTypedRowData * handle address types cidr, inet and macaddr * adjust response parser and docs for annotations * convert unknown types to string * add documentation for postgres datasource * add another example query with metric column * set more helpful default query * update help text in query editor * handle NULL in value column of timeseries query * add __timeGroup macro * add test for __timeGroup macro * document __timeGroup and set proper default query for annotations * fix typos in docs * add postgres to list of datasources * add postgres to builtInPlugins * mysql: refactoring as prep for merging postgres Refactors out the initialization of the xorm engine and the query logic for an sql data source. * mysql: rename refactoring + test update * postgres:refactor to use SqlEngine(same as mysql) Refactored to use a common base class with the MySql data source. Other changes from the original PR: - Changed time column to be time_sec to allow other time units in the future and to be the same as MySQL - Changed integration test to test the main Query method rather than the private transformToTable method - Changed the __timeSec macro name to __timeEpoch - Renamed PostgresExecutor to PostgresQueryEndpoint Fixes #9209 (the original PR) * postgres: encrypt password on config page With some other cosmetic changes to the config page: - placeholder texts - reset button for the password after it has been encrypted. - default value for the sslmode field. * postgres: change back col name to time from time_sec * postgres mysql: remove annotation title Title has been removed from annotations * postgres: fix images for docs page * postgres mysql: fix specs
2017-10-10 08:19:14 -05:00
min(value_double),
'min' as metric
FROM test_data
WHERE $__timeFilter(time_date_time)
GROUP BY time
ORDER BY time
Postgres Data Source (#9475) * add postgresql datasource * add rest of files for postgres datasource * fix timeseries query, remove unused code * consistent naming, refactoring * s/mysql/postgres/ * s/mysql/postgres/ * couple more tests * tests for more datatypes * fix macros for postgres * add __timeSec macro * add frontend for postgres datasource * adjust documentation * fix formatting * add proper plugin description * merge editor changes from mysql * port changes from mysql datasource * set proper defaultQuery for postgres * add time_sec to timeseries query accept int for value for timeseries query * revert allowing time_sec and handle int or float values as unix timestamp for "time" column * fix tslint error * handle decimal values in timeseries query * allow setting sslmode for postgres datasource * use type switch for handling data types * fix value for timeseries query * refactor timeseries queries to make them more flexible * remove debug statement from inner loop in type conversion * use plain for loop in getTypedRowData * fix timeseries queries * adjust postgres datasource to tsdb refactoring * adjust postgres datasource to frontend changes * update lib/pq to latest version * move type conversion to getTypedRowData * handle address types cidr, inet and macaddr * adjust response parser and docs for annotations * convert unknown types to string * add documentation for postgres datasource * add another example query with metric column * set more helpful default query * update help text in query editor * handle NULL in value column of timeseries query * add __timeGroup macro * add test for __timeGroup macro * document __timeGroup and set proper default query for annotations * fix typos in docs * add postgres to list of datasources * add postgres to builtInPlugins * mysql: refactoring as prep for merging postgres Refactors out the initialization of the xorm engine and the query logic for an sql data source. * mysql: rename refactoring + test update * postgres:refactor to use SqlEngine(same as mysql) Refactored to use a common base class with the MySql data source. Other changes from the original PR: - Changed time column to be time_sec to allow other time units in the future and to be the same as MySQL - Changed integration test to test the main Query method rather than the private transformToTable method - Changed the __timeSec macro name to __timeEpoch - Renamed PostgresExecutor to PostgresQueryEndpoint Fixes #9209 (the original PR) * postgres: encrypt password on config page With some other cosmetic changes to the config page: - placeholder texts - reset button for the password after it has been encrypted. - default value for the sslmode field. * postgres: change back col name to time from time_sec * postgres mysql: remove annotation title Title has been removed from annotations * postgres: fix images for docs page * postgres mysql: fix specs
2017-10-10 08:19:14 -05:00
```
Example with multiple columns:
```sql
SELECT
$__timeGroup(time_date_time,'5m') as time,
Postgres Data Source (#9475) * add postgresql datasource * add rest of files for postgres datasource * fix timeseries query, remove unused code * consistent naming, refactoring * s/mysql/postgres/ * s/mysql/postgres/ * couple more tests * tests for more datatypes * fix macros for postgres * add __timeSec macro * add frontend for postgres datasource * adjust documentation * fix formatting * add proper plugin description * merge editor changes from mysql * port changes from mysql datasource * set proper defaultQuery for postgres * add time_sec to timeseries query accept int for value for timeseries query * revert allowing time_sec and handle int or float values as unix timestamp for "time" column * fix tslint error * handle decimal values in timeseries query * allow setting sslmode for postgres datasource * use type switch for handling data types * fix value for timeseries query * refactor timeseries queries to make them more flexible * remove debug statement from inner loop in type conversion * use plain for loop in getTypedRowData * fix timeseries queries * adjust postgres datasource to tsdb refactoring * adjust postgres datasource to frontend changes * update lib/pq to latest version * move type conversion to getTypedRowData * handle address types cidr, inet and macaddr * adjust response parser and docs for annotations * convert unknown types to string * add documentation for postgres datasource * add another example query with metric column * set more helpful default query * update help text in query editor * handle NULL in value column of timeseries query * add __timeGroup macro * add test for __timeGroup macro * document __timeGroup and set proper default query for annotations * fix typos in docs * add postgres to list of datasources * add postgres to builtInPlugins * mysql: refactoring as prep for merging postgres Refactors out the initialization of the xorm engine and the query logic for an sql data source. * mysql: rename refactoring + test update * postgres:refactor to use SqlEngine(same as mysql) Refactored to use a common base class with the MySql data source. Other changes from the original PR: - Changed time column to be time_sec to allow other time units in the future and to be the same as MySQL - Changed integration test to test the main Query method rather than the private transformToTable method - Changed the __timeSec macro name to __timeEpoch - Renamed PostgresExecutor to PostgresQueryEndpoint Fixes #9209 (the original PR) * postgres: encrypt password on config page With some other cosmetic changes to the config page: - placeholder texts - reset button for the password after it has been encrypted. - default value for the sslmode field. * postgres: change back col name to time from time_sec * postgres mysql: remove annotation title Title has been removed from annotations * postgres: fix images for docs page * postgres mysql: fix specs
2017-10-10 08:19:14 -05:00
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
Postgres Data Source (#9475) * add postgresql datasource * add rest of files for postgres datasource * fix timeseries query, remove unused code * consistent naming, refactoring * s/mysql/postgres/ * s/mysql/postgres/ * couple more tests * tests for more datatypes * fix macros for postgres * add __timeSec macro * add frontend for postgres datasource * adjust documentation * fix formatting * add proper plugin description * merge editor changes from mysql * port changes from mysql datasource * set proper defaultQuery for postgres * add time_sec to timeseries query accept int for value for timeseries query * revert allowing time_sec and handle int or float values as unix timestamp for "time" column * fix tslint error * handle decimal values in timeseries query * allow setting sslmode for postgres datasource * use type switch for handling data types * fix value for timeseries query * refactor timeseries queries to make them more flexible * remove debug statement from inner loop in type conversion * use plain for loop in getTypedRowData * fix timeseries queries * adjust postgres datasource to tsdb refactoring * adjust postgres datasource to frontend changes * update lib/pq to latest version * move type conversion to getTypedRowData * handle address types cidr, inet and macaddr * adjust response parser and docs for annotations * convert unknown types to string * add documentation for postgres datasource * add another example query with metric column * set more helpful default query * update help text in query editor * handle NULL in value column of timeseries query * add __timeGroup macro * add test for __timeGroup macro * document __timeGroup and set proper default query for annotations * fix typos in docs * add postgres to list of datasources * add postgres to builtInPlugins * mysql: refactoring as prep for merging postgres Refactors out the initialization of the xorm engine and the query logic for an sql data source. * mysql: rename refactoring + test update * postgres:refactor to use SqlEngine(same as mysql) Refactored to use a common base class with the MySql data source. Other changes from the original PR: - Changed time column to be time_sec to allow other time units in the future and to be the same as MySQL - Changed integration test to test the main Query method rather than the private transformToTable method - Changed the __timeSec macro name to __timeEpoch - Renamed PostgresExecutor to PostgresQueryEndpoint Fixes #9209 (the original PR) * postgres: encrypt password on config page With some other cosmetic changes to the config page: - placeholder texts - reset button for the password after it has been encrypted. - default value for the sslmode field. * postgres: change back col name to time from time_sec * postgres mysql: remove annotation title Title has been removed from annotations * postgres: fix images for docs page * postgres mysql: fix specs
2017-10-10 08:19:14 -05:00
```
## Templating
Instead of hard-coding things like server, application and sensor name in you metric queries you can use variables in their place. Variables are shown as dropdown select boxes at the top of the dashboard. These dropdowns makes it easy to change the data being displayed in your dashboard.
Checkout the [Templating]({{< relref "reference/templating.md" >}}) documentation for an introduction to the templating feature and the different types of template variables.
### Query Variable
If you add a template variable of the type `Query`, you can write a PostgreSQL query that can
return things like measurement names, key names or key values that are shown as a dropdown select box.
For example, you can have a variable that contains all values for the `hostname` column in a table if you specify a query like this in the templating variable *Query* setting.
```sql
SELECT hostname FROM host
```
A query can return multiple columns and Grafana will automatically create a list from them. For example, the query below will return a list with values from `hostname` and `hostname2`.
```sql
SELECT host.hostname, other_host.hostname2 FROM host JOIN other_host ON host.city = other_host.city
```
Another option is a query that can create a key/value variable. The query should return two columns that are named `__text` and `__value`. The `__text` column value should be unique (if it is not unique then the first value is used). The options in the dropdown will have a text and value that allows you to have a friendly name as text and an id as the value. An example query with `hostname` as the text and `id` as the value:
```sql
SELECT hostname AS __text, id AS __value FROM host
```
You can also create nested variables. For example if you had another variable named `region`. Then you could have
the hosts variable only show hosts from the current selected region with a query like this (if `region` is a multi-value variable then use the `IN` comparison operator rather than `=` to match against multiple values):
```sql
SELECT hostname FROM host WHERE region IN($region)
```
### Using Variables in Queries
Template variables are quoted automatically so if it is a string value do not wrap them in quotes in where clauses. If the variable is a multi-value variable then use the `IN` comparison operator rather than `=` to match against multiple values.
There are two syntaxes:
`$<varname>` Example with a template variable named `hostname`:
```sql
SELECT
atimestamp as time,
aint as value
FROM table
WHERE $__timeFilter(atimestamp) and hostname in($hostname)
ORDER BY atimestamp ASC
```
`[[varname]]` Example with a template variable named `hostname`:
```sql
SELECT
atimestamp as time,
aint as value
FROM table
WHERE $__timeFilter(atimestamp) and hostname in([[hostname]])
ORDER BY atimestamp ASC
```
## Alerting
Time series queries should work in alerting conditions. Table formatted queries is not yet supported in alert rule
conditions.