mirror of https://github.com/grafana/grafana
prometheushacktoberfestmetricsmonitoringalertinggrafanagoinfluxdbmysqlpostgresanalyticsdata-visualizationdashboardbusiness-intelligenceelasticsearch
You can not select more than 25 topics
Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
622 lines
24 KiB
622 lines
24 KiB
|
8 years ago
|
+++
|
||
|
5 years ago
|
title = "Microsoft SQL Server"
|
||
|
8 years ago
|
description = "Guide for using Microsoft SQL Server in Grafana"
|
||
|
8 years ago
|
keywords = ["grafana", "MSSQL", "Microsoft", "SQL", "guide", "Azure SQL Database"]
|
||
|
8 years ago
|
type = "docs"
|
||
|
5 years ago
|
aliases = ["/docs/grafana/latest/features/datasources/mssql/"]
|
||
|
8 years ago
|
[menu.docs]
|
||
|
|
name = "Microsoft SQL Server"
|
||
|
|
parent = "datasources"
|
||
|
5 years ago
|
weight = 900
|
||
|
8 years ago
|
+++
|
||
|
|
|
||
|
|
# Using Microsoft SQL Server in Grafana
|
||
|
|
|
||
|
8 years ago
|
> Only available in Grafana v5.1+.
|
||
|
|
|
||
|
8 years ago
|
Grafana ships with a built-in Microsoft SQL Server (MSSQL) data source plugin that allows you to query and visualize data from any Microsoft SQL Server 2005 or newer, including Microsoft Azure SQL Database.
|
||
|
8 years ago
|
|
||
|
|
## Adding the data source
|
||
|
|
|
||
|
|
1. Open the side menu by clicking the Grafana icon in the top header.
|
||
|
5 years ago
|
1. In the side menu under the `Configuration` link you should find a link named `Data Sources`.
|
||
|
|
1. Click the `+ Add data source` button in the top header.
|
||
|
|
1. Select *Microsoft SQL Server* from the *Type* dropdown.
|
||
|
8 years ago
|
|
||
|
8 years ago
|
### Data source options
|
||
|
|
|
||
|
|
Name | Description
|
||
|
|
------------ | -------------
|
||
|
6 years ago
|
*Name* | The data source name. This is how you refer to the data source in panels and queries.
|
||
|
8 years ago
|
*Default* | Default data source means that it will be pre-selected for new panels.
|
||
|
8 years ago
|
*Host* | The IP address/hostname and optional port of your MSSQL instance. If port is omitted, default 1433 will be used.
|
||
|
8 years ago
|
*Database* | Name of your MSSQL database.
|
||
|
|
*User* | Database user's login/username
|
||
|
|
*Password* | Database user's password
|
||
|
7 years ago
|
*Encrypt* | This option determines whether or to which extent a secure SSL TCP/IP connection will be negotiated with the server, default `false` (Grafana v5.4+).
|
||
|
7 years ago
|
*Max open* | The maximum number of open connections to the database, default `unlimited` (Grafana v5.4+).
|
||
|
|
*Max idle* | The maximum number of connections in the idle connection pool, default `2` (Grafana v5.4+).
|
||
|
|
*Max lifetime* | The maximum amount of time in seconds a connection may be reused, default `14400`/4 hours (Grafana v5.4+).
|
||
|
8 years ago
|
|
||
|
7 years ago
|
### Min time interval
|
||
|
7 years ago
|
|
||
|
5 years ago
|
A lower limit for the [$__interval]({{< relref "../variables/variable-types/_index.md#the-interval-variable" >}}) and [$__interval_ms]({{< relref "../variables/variable-types/_index.md#the-interval-ms-variable" >}}) variables.
|
||
|
7 years ago
|
Recommended to be set to write frequency, for example `1m` if your data is written every minute.
|
||
|
7 years ago
|
This option can also be overridden/configured in a dashboard panel under data source options. It's important to note that this value **needs** to be formatted as a
|
||
|
|
number followed by a valid time identifier, e.g. `1m` (1 minute) or `30s` (30 seconds). The following time identifiers are supported:
|
||
|
|
|
||
|
|
Identifier | Description
|
||
|
|
------------ | -------------
|
||
|
|
`y` | year
|
||
|
|
`M` | month
|
||
|
|
`w` | week
|
||
|
|
`d` | day
|
||
|
|
`h` | hour
|
||
|
|
`m` | minute
|
||
|
|
`s` | second
|
||
|
|
`ms` | millisecond
|
||
|
|
|
||
|
8 years ago
|
### Database User Permissions (Important!)
|
||
|
|
|
||
|
|
The database user you specify when you add the data source should only be granted SELECT permissions on
|
||
|
6 years ago
|
the specified database and tables you want to query. Grafana does not validate that the query is safe. The query
|
||
|
8 years ago
|
could include any SQL statement. For example, statements like `DELETE FROM user;` and `DROP TABLE user;` would be
|
||
|
8 years ago
|
executed. To protect against this we **Highly** recommend you create a specific MSSQL user with restricted permissions.
|
||
|
8 years ago
|
|
||
|
|
Example:
|
||
|
|
|
||
|
|
```sql
|
||
|
|
CREATE USER grafanareader WITH PASSWORD 'password'
|
||
|
|
GRANT SELECT ON dbo.YourTable3 TO grafanareader
|
||
|
|
```
|
||
|
|
|
||
|
|
Make sure the user does not get any unwanted privileges from the public role.
|
||
|
|
|
||
|
7 years ago
|
### Known Issues
|
||
|
|
|
||
|
|
If you're using an older version of Microsoft SQL Server like 2008 and 2008R2 you may need to disable encryption to be able to connect.
|
||
|
|
If possible, we recommend you to use the latest service pack available for optimal compatibility.
|
||
|
|
|
||
|
8 years ago
|
## Query Editor
|
||
|
8 years ago
|
|
||
|
8 years ago
|
{{< docs-imagebox img="/img/docs/v51/mssql_query_editor.png" class="docs-image--no-shadow" >}}
|
||
|
|
|
||
|
6 years ago
|
You will find the MSSQL query editor in the metrics tab in Graph, Singlestat or Table panel's edit mode. You enter edit mode by clicking the
|
||
|
8 years ago
|
panel title, then edit. The editor allows you to define a SQL query to select data to be visualized.
|
||
|
|
|
||
|
|
1. Select *Format as* `Time series` (for use in Graph or Singlestat panel's among others) or `Table` (for use in Table panel among others).
|
||
|
5 years ago
|
1. This is the actual editor where you write your SQL queries.
|
||
|
|
1. Show help section for MSSQL below the query editor.
|
||
|
|
1. Show actual executed SQL query. Will be available first after a successful query has been executed.
|
||
|
|
1. Add an additional query where an additional query editor will be displayed.
|
||
|
8 years ago
|
|
||
|
|
<div class="clearfix"></div>
|
||
|
|
|
||
|
8 years ago
|
## Macros
|
||
|
|
|
||
|
|
To simplify syntax and to allow for dynamic parts, like date range filters, the query can contain macros.
|
||
|
|
|
||
|
|
Macro example | Description
|
||
|
|
------------ | -------------
|
||
|
6 years ago
|
*`$__time(dateColumn)`* | Will be replaced by an expression to rename the column to *time*. For example, *dateColumn as time*
|
||
|
|
*`$__timeEpoch(dateColumn)`* | Will be replaced by an expression to convert a DATETIME column type to Unix timestamp and rename it to *time*. <br/>For example, *DATEDIFF(second, '1970-01-01', dateColumn) AS time*
|
||
|
|
*`$__timeFilter(dateColumn)`* | Will be replaced by a time range filter using the specified column name. <br/>For example, *dateColumn BETWEEN '2017-04-21T05:01:17Z' AND '2017-04-21T05:06:17Z'*
|
||
|
|
*`$__timeFrom()`* | Will be replaced by the start of the currently active time selection. For example, *'2017-04-21T05:01:17Z'*
|
||
|
|
*`$__timeTo()`* | Will be replaced by the end of the currently active time selection. For example, *'2017-04-21T05:06:17Z'*
|
||
|
|
*`$__timeGroup(dateColumn,'5m'[, fillvalue])`* | Will be replaced by an expression usable in GROUP BY clause. Providing a *fillValue* of *NULL* or *floating value* will automatically fill empty series in timerange with that value. <br/>For example, *CAST(ROUND(DATEDIFF(second, '1970-01-01', time_column)/300.0, 0) as bigint)\*300*.
|
||
|
|
*`$__timeGroup(dateColumn,'5m', 0)`* | Same as above but with a fill parameter so missing points in that series will be added by grafana and 0 will be used as value.
|
||
|
|
*`$__timeGroup(dateColumn,'5m', NULL)`* | Same as above but NULL will be used as value for missing points.
|
||
|
|
*`$__timeGroup(dateColumn,'5m', previous)`* | Same as above but the previous value in that series will be used as fill value if no value has been seen yet NULL will be used (only available in Grafana 5.3+).
|
||
|
|
*`$__timeGroupAlias(dateColumn,'5m')`* | Will be replaced identical to $__timeGroup but with an added column alias (only available in Grafana 5.3+).
|
||
|
|
*`$__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*
|
||
|
|
*`$__unixEpochNanoFilter(dateColumn)`* | Will be replaced by a time range filter using the specified column name with times represented as nanosecond timestamp. For example, *dateColumn > 1494410783152415214 AND dateColumn < 1494497183142514872*
|
||
|
|
*`$__unixEpochNanoFrom()`* | Will be replaced by the start of the currently active time selection as nanosecond timestamp. For example, *1494410783152415214*
|
||
|
|
*`$__unixEpochNanoTo()`* | Will be replaced by the end of the currently active time selection as nanosecond timestamp. For example, *1494497183142514872*
|
||
|
|
*`$__unixEpochGroup(dateColumn,'5m', [fillmode])`* | Same as $__timeGroup but for times stored as Unix timestamp (only available in Grafana 5.3+).
|
||
|
|
*`$__unixEpochGroupAlias(dateColumn,'5m', [fillmode])`* | Same as above but also adds a column alias (only available in Grafana 5.3+).
|
||
|
8 years ago
|
|
||
|
|
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 has 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
|
||
|
8 years ago
|
|
||
|
6 years ago
|
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 and rows your query returns.
|
||
|
8 years ago
|
|
||
|
8 years ago
|
**Example database table:**
|
||
|
|
|
||
|
|
```sql
|
||
|
|
CREATE TABLE [event] (
|
||
|
|
time_sec bigint,
|
||
|
|
description nvarchar(100),
|
||
|
|
tags nvarchar(100),
|
||
|
|
)
|
||
|
|
```
|
||
|
|
|
||
|
|
```sql
|
||
|
|
CREATE TABLE [mssql_types] (
|
||
|
|
c_bit bit, c_tinyint tinyint, c_smallint smallint, c_int int, c_bigint bigint, c_money money, c_smallmoney smallmoney, c_numeric numeric(10,5),
|
||
|
|
c_real real, c_decimal decimal(10,2), c_float float,
|
||
|
|
c_char char(10), c_varchar varchar(10), c_text text,
|
||
|
|
c_nchar nchar(12), c_nvarchar nvarchar(12), c_ntext ntext,
|
||
|
|
c_datetime datetime, c_datetime2 datetime2, c_smalldatetime smalldatetime, c_date date, c_time time, c_datetimeoffset datetimeoffset
|
||
|
|
)
|
||
|
|
|
||
|
|
INSERT INTO [mssql_types]
|
||
|
|
SELECT
|
||
|
|
1, 5, 20020, 980300, 1420070400, '$20000.15', '£2.15', 12345.12,
|
||
|
|
1.11, 2.22, 3.33,
|
||
|
|
'char10', 'varchar10', 'text',
|
||
|
|
N'☺nchar12☺', N'☺nvarchar12☺', N'☺text☺',
|
||
|
5 years ago
|
GETDATE(), CAST(GETDATE() AS DATETIME2), CAST(GETDATE() AS SMALLDATETIME), CAST(GETDATE() AS DATE), CAST(GETDATE() AS TIME), SWITCHOFFSET(CAST(GETDATE() AS DATETIMEOFFSET), '-07:00')
|
||
|
8 years ago
|
```
|
||
|
|
|
||
|
8 years ago
|
Query editor with example query:
|
||
|
|
|
||
|
8 years ago
|
{{< docs-imagebox img="/img/docs/v51/mssql_table_query.png" max-width="500px" class="docs-image--no-shadow" >}}
|
||
|
8 years ago
|
|
||
|
|
|
||
|
|
The query:
|
||
|
|
|
||
|
|
```sql
|
||
|
8 years ago
|
SELECT * FROM [mssql_types]
|
||
|
8 years ago
|
```
|
||
|
|
|
||
|
8 years ago
|
You can control the name of the Table panel columns by using regular `AS ` SQL column selection syntax. Example:
|
||
|
|
|
||
|
|
```sql
|
||
|
|
SELECT
|
||
|
|
c_bit as [column1], c_tinyint as [column2]
|
||
|
|
FROM
|
||
|
|
[mssql_types]
|
||
|
|
```
|
||
|
8 years ago
|
|
||
|
|
The resulting table panel:
|
||
|
|
|
||
|
8 years ago
|
{{< docs-imagebox img="/img/docs/v51/mssql_table_result.png" max-width="1489px" class="docs-image--no-shadow" >}}
|
||
|
|
|
||
|
|
## Time series queries
|
||
|
|
|
||
|
6 years ago
|
If you set `Format as` to `Time series`, for use in Graph panel for example, then the query must have a column named `time` that returns either a SQL datetime or any numeric datatype representing Unix epoch in seconds. You may return a column named `metric` that is used as metric name for the value column. Any column except `time` and `metric` is treated as a value column. If you omit the `metric` column, the name of the value column will be the metric name. You may select multiple value columns, each will have its name as metric.
|
||
|
7 years ago
|
If you return multiple value columns and a column named `metric` then this column is used as prefix for the series name (only available in Grafana 5.3+).
|
||
|
8 years ago
|
|
||
|
7 years ago
|
Resultsets of time series queries need to be sorted by time.
|
||
|
|
|
||
|
8 years ago
|
**Example database table:**
|
||
|
|
|
||
|
|
```sql
|
||
|
|
CREATE TABLE [event] (
|
||
|
|
time_sec bigint,
|
||
|
|
description nvarchar(100),
|
||
|
|
tags nvarchar(100),
|
||
|
|
)
|
||
|
|
```
|
||
|
|
|
||
|
8 years ago
|
|
||
|
8 years ago
|
```sql
|
||
|
|
CREATE TABLE metric_values (
|
||
|
|
time datetime,
|
||
|
|
measurement nvarchar(100),
|
||
|
|
valueOne int,
|
||
|
|
valueTwo int,
|
||
|
|
)
|
||
|
|
|
||
|
|
INSERT metric_values (time, measurement, valueOne, valueTwo) VALUES('2018-03-15 12:30:00', 'Metric A', 62, 6)
|
||
|
|
INSERT metric_values (time, measurement, valueOne, valueTwo) VALUES('2018-03-15 12:30:00', 'Metric B', 49, 11)
|
||
|
|
...
|
||
|
|
INSERT metric_values (time, measurement, valueOne, valueTwo) VALUES('2018-03-15 13:55:00', 'Metric A', 14, 25)
|
||
|
|
INSERT metric_values (time, measurement, valueOne, valueTwo) VALUES('2018-03-15 13:55:00', 'Metric B', 48, 10)
|
||
|
8 years ago
|
|
||
|
8 years ago
|
```
|
||
|
8 years ago
|
|
||
|
8 years ago
|
{{< docs-imagebox img="/img/docs/v51/mssql_time_series_one.png" class="docs-image--no-shadow docs-image--right" >}}
|
||
|
|
|
||
|
|
**Example with one `value` and one `metric` column.**
|
||
|
8 years ago
|
|
||
|
|
```sql
|
||
|
|
SELECT
|
||
|
8 years ago
|
time,
|
||
|
|
valueOne,
|
||
|
|
measurement as metric
|
||
|
|
FROM
|
||
|
|
metric_values
|
||
|
|
WHERE
|
||
|
|
$__timeFilter(time)
|
||
|
|
ORDER BY 1
|
||
|
8 years ago
|
```
|
||
|
|
|
||
|
5 years ago
|
When the above query is used in a graph panel, it will produce two series named `Metric A` and `Metric B` with the values `valueOne` and `valueTwo` plotted over `time`.
|
||
|
8 years ago
|
|
||
|
|
<div class="clearfix"></div>
|
||
|
|
|
||
|
|
{{< docs-imagebox img="/img/docs/v51/mssql_time_series_two.png" class="docs-image--no-shadow docs-image--right" >}}
|
||
|
|
|
||
|
7 years ago
|
**Example with multiple `value` columns:**
|
||
|
8 years ago
|
|
||
|
|
```sql
|
||
|
|
SELECT
|
||
|
8 years ago
|
time,
|
||
|
|
valueOne,
|
||
|
|
valueTwo
|
||
|
|
FROM
|
||
|
|
metric_values
|
||
|
|
WHERE
|
||
|
|
$__timeFilter(time)
|
||
|
|
ORDER BY 1
|
||
|
8 years ago
|
```
|
||
|
|
|
||
|
5 years ago
|
When the above query is used in a graph panel, it will produce two series named `Metric A` and `Metric B` with the values `valueOne` and `valueTwo` plotted over `time`.
|
||
|
8 years ago
|
|
||
|
|
<div class="clearfix"></div>
|
||
|
|
|
||
|
|
{{< docs-imagebox img="/img/docs/v51/mssql_time_series_three.png" class="docs-image--no-shadow docs-image--right" >}}
|
||
|
|
|
||
|
|
**Example using the $__timeGroup macro:**
|
||
|
8 years ago
|
|
||
|
|
```sql
|
||
|
|
SELECT
|
||
|
8 years ago
|
$__timeGroup(time, '3m') as time,
|
||
|
|
measurement as metric,
|
||
|
|
avg(valueOne)
|
||
|
|
FROM
|
||
|
|
metric_values
|
||
|
|
WHERE
|
||
|
|
$__timeFilter(time)
|
||
|
|
GROUP BY
|
||
|
|
$__timeGroup(time, '3m'),
|
||
|
|
measurement
|
||
|
|
ORDER BY 1
|
||
|
8 years ago
|
```
|
||
|
|
|
||
|
5 years ago
|
When the above query is used in a graph panel, it will produce two series named `Metric A` and `Metric B` with the values `valueOne` and `valueTwo` plotted over `time`.
|
||
|
|
Any two series lacking a value in a three-minute window will render a line between those two lines. You'll notice that the graph to the right never goes down to zero.
|
||
|
8 years ago
|
|
||
|
|
<div class="clearfix"></div>
|
||
|
|
|
||
|
|
{{< docs-imagebox img="/img/docs/v51/mssql_time_series_four.png" class="docs-image--no-shadow docs-image--right" >}}
|
||
|
|
|
||
|
|
**Example using the $__timeGroup macro with fill parameter set to zero:**
|
||
|
|
|
||
|
|
```sql
|
||
|
|
SELECT
|
||
|
|
$__timeGroup(time, '3m', 0) as time,
|
||
|
|
measurement as metric,
|
||
|
|
sum(valueTwo)
|
||
|
|
FROM
|
||
|
|
metric_values
|
||
|
|
WHERE
|
||
|
|
$__timeFilter(time)
|
||
|
|
GROUP BY
|
||
|
|
$__timeGroup(time, '3m'),
|
||
|
|
measurement
|
||
|
|
ORDER BY 1
|
||
|
|
```
|
||
|
8 years ago
|
|
||
|
6 years ago
|
When the above query is used in a graph panel, the result is two series named `Metric A` and `Metric B` with a sum of `valueTwo` plotted over `time`.
|
||
|
8 years ago
|
Any series lacking a value in a 3 minute window will have a value of zero which you'll see rendered in the graph to the right.
|
||
|
8 years ago
|
|
||
|
|
## Templating
|
||
|
|
|
||
|
6 years ago
|
Instead of hard-coding things like server, application and sensor name in your metric queries you can use variables in their place. Variables are shown as dropdown select boxes at the top of the dashboard. These dropdowns make it easy to change the data being displayed in your dashboard.
|
||
|
8 years ago
|
|
||
|
5 years ago
|
Check out the [Templating]({{< relref "../variables/_index.md" >}}) documentation for an introduction to the templating feature and the different types of template variables.
|
||
|
8 years ago
|
|
||
|
|
### Query Variable
|
||
|
|
|
||
|
|
If you add a template variable of the type `Query`, you can write a MSSQL 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]
|
||
|
|
```
|
||
|
|
|
||
|
6 years ago
|
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 allow 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:
|
||
|
8 years ago
|
|
||
|
|
```sql
|
||
|
|
SELECT hostname __text, id __value FROM host
|
||
|
|
```
|
||
|
|
|
||
|
5 years ago
|
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):
|
||
|
8 years ago
|
|
||
|
|
```sql
|
||
|
|
SELECT hostname FROM host WHERE region IN ($region)
|
||
|
|
```
|
||
|
|
|
||
|
|
### Using Variables in Queries
|
||
|
8 years ago
|
|
||
|
8 years ago
|
> From Grafana 4.3.0 to 4.6.0, template variables are always quoted automatically so if it is a string value do not wrap them in quotes in where clauses.
|
||
|
|
>
|
||
|
|
> From Grafana 5.0.0, template variable values are only quoted when the template variable is a `multi-value`.
|
||
|
8 years ago
|
|
||
|
|
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 time,
|
||
|
|
aint value
|
||
|
|
FROM table
|
||
|
|
WHERE $__timeFilter(atimestamp) and hostname in($hostname)
|
||
|
|
ORDER BY atimestamp
|
||
|
|
```
|
||
|
|
|
||
|
|
`[[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
|
||
|
|
```
|
||
|
|
|
||
|
8 years ago
|
#### Disabling Quoting for Multi-value Variables
|
||
|
|
|
||
|
|
Grafana automatically creates a quoted, comma-separated string for multi-value variables. For example: if `server01` and `server02` are selected then it will be formatted as: `'server01', 'server02'`. Do disable quoting, use the csv formatting option for variables:
|
||
|
|
|
||
|
|
`${servers:csv}`
|
||
|
|
|
||
|
5 years ago
|
Read more about variable formatting options in the [Variables]({{< relref "../variables/variable-types/_index.md#advanced-formatting-options" >}}) documentation.
|
||
|
8 years ago
|
|
||
|
8 years ago
|
## Annotations
|
||
|
|
|
||
|
5 years ago
|
[Annotations]({{< relref "../dashboards/annotations.md" >}}) allow you to overlay rich event information on top of graphs. You add annotation queries via the Dashboard menu / Annotations view.
|
||
|
8 years ago
|
|
||
|
8 years ago
|
**Columns:**
|
||
|
|
|
||
|
|
Name | Description
|
||
|
|
------------ | -------------
|
||
|
6 years ago
|
time | The name of the date/time field. Could be a column with a native SQL date/time data type or epoch value.
|
||
|
6 years ago
|
timeend | Optional name of the end date/time field. Could be a column with a native SQL date/time data type or epoch value. (Grafana v6.6+)
|
||
|
8 years ago
|
text | Event description field.
|
||
|
|
tags | Optional field name to use for event tags as a comma separated string.
|
||
|
|
|
||
|
|
**Example database tables:**
|
||
|
|
|
||
|
|
```sql
|
||
|
|
CREATE TABLE [events] (
|
||
|
|
time_sec bigint,
|
||
|
|
description nvarchar(100),
|
||
|
|
tags nvarchar(100),
|
||
|
|
)
|
||
|
|
```
|
||
|
|
|
||
|
|
We also use the database table defined in [Time series queries](#time-series-queries).
|
||
|
|
|
||
|
8 years ago
|
**Example query using time column with epoch values:**
|
||
|
8 years ago
|
|
||
|
|
```sql
|
||
|
|
SELECT
|
||
|
|
time_sec as time,
|
||
|
|
description as [text],
|
||
|
|
tags
|
||
|
6 years ago
|
FROM
|
||
|
|
[events]
|
||
|
|
WHERE
|
||
|
|
$__unixEpochFilter(time_sec)
|
||
|
|
ORDER BY 1
|
||
|
|
```
|
||
|
|
|
||
|
|
**Example region query using time and timeend columns with epoch values:**
|
||
|
|
|
||
|
|
> Only available in Grafana v6.6+.
|
||
|
|
|
||
|
|
```sql
|
||
|
|
SELECT
|
||
|
|
time_sec as time,
|
||
|
|
time_end_sec as timeend,
|
||
|
|
description as [text],
|
||
|
|
tags
|
||
|
8 years ago
|
FROM
|
||
|
|
[events]
|
||
|
|
WHERE
|
||
|
|
$__unixEpochFilter(time_sec)
|
||
|
|
ORDER BY 1
|
||
|
|
```
|
||
|
|
|
||
|
6 years ago
|
**Example query using time column of native SQL date/time data type:**
|
||
|
8 years ago
|
|
||
|
|
```sql
|
||
|
|
SELECT
|
||
|
8 years ago
|
time,
|
||
|
|
measurement as text,
|
||
|
|
convert(varchar, valueOne) + ',' + convert(varchar, valueTwo) as tags
|
||
|
8 years ago
|
FROM
|
||
|
8 years ago
|
metric_values
|
||
|
8 years ago
|
WHERE
|
||
|
|
$__timeFilter(time_column)
|
||
|
8 years ago
|
ORDER BY 1
|
||
|
8 years ago
|
```
|
||
|
|
|
||
|
8 years ago
|
## Stored procedure support
|
||
|
8 years ago
|
|
||
|
6 years ago
|
Stored procedures have been verified to work. However, please note that we haven't done anything special to support this, so there might be edge cases where it won't work as you would expect.
|
||
|
8 years ago
|
Stored procedures should be supported in table, time series and annotation queries as long as you use the same naming of columns and return data in the same format as describe above under respective section.
|
||
|
|
|
||
|
|
Please note that any macro function will not work inside a stored procedure.
|
||
|
|
|
||
|
|
### Examples
|
||
|
8 years ago
|
|
||
|
8 years ago
|
{{< docs-imagebox img="/img/docs/v51/mssql_metrics_graph.png" class="docs-image--no-shadow docs-image--right" >}}
|
||
|
5 years ago
|
For the following examples, the database table is defined in [Time series queries](#time-series-queries). Let's say that we want to visualize four series in a graph panel, such as all combinations of columns `valueOne`, `valueTwo` and `measurement`. Graph panel to the right visualizes what we want to achieve. To solve this, we need to use two queries:
|
||
|
8 years ago
|
|
||
|
|
**First query:**
|
||
|
8 years ago
|
|
||
|
8 years ago
|
```sql
|
||
|
|
SELECT
|
||
|
|
$__timeGroup(time, '5m') as time,
|
||
|
|
measurement + ' - value one' as metric,
|
||
|
|
avg(valueOne) as valueOne
|
||
|
|
FROM
|
||
|
|
metric_values
|
||
|
|
WHERE
|
||
|
|
$__timeFilter(time)
|
||
|
|
GROUP BY
|
||
|
|
$__timeGroup(time, '5m'),
|
||
|
|
measurement
|
||
|
|
ORDER BY 1
|
||
|
|
```
|
||
|
|
|
||
|
|
**Second query:**
|
||
|
|
```sql
|
||
|
|
SELECT
|
||
|
|
$__timeGroup(time, '5m') as time,
|
||
|
|
measurement + ' - value two' as metric,
|
||
|
|
avg(valueTwo) as valueTwo
|
||
|
|
FROM
|
||
|
|
metric_values
|
||
|
|
GROUP BY
|
||
|
|
$__timeGroup(time, '5m'),
|
||
|
|
measurement
|
||
|
|
ORDER BY 1
|
||
|
|
```
|
||
|
|
|
||
|
|
#### Stored procedure using time in epoch format
|
||
|
8 years ago
|
|
||
|
8 years ago
|
We can define a stored procedure that will return all data we need to render 4 series in a graph panel like above.
|
||
|
|
In this case the stored procedure accepts two parameters `@from` and `@to` of `int` data types which should be a timerange (from-to) in epoch format
|
||
|
|
which will be used to filter the data to return from the stored procedure.
|
||
|
|
|
||
|
6 years ago
|
We're mimicking the `$__timeGroup(time, '5m')` in the select and group by expressions, and that's why there are a lot of lengthy expressions needed -
|
||
|
8 years ago
|
these could be extracted to MSSQL functions, if wanted.
|
||
|
|
|
||
|
|
```sql
|
||
|
|
CREATE PROCEDURE sp_test_epoch(
|
||
|
|
@from int,
|
||
|
|
@to int
|
||
|
|
) AS
|
||
|
|
BEGIN
|
||
|
|
SELECT
|
||
|
|
cast(cast(DATEDIFF(second, {d '1970-01-01'}, DATEADD(second, DATEDIFF(second,GETDATE(),GETUTCDATE()), time))/600 as int)*600 as int) as time,
|
||
|
|
measurement + ' - value one' as metric,
|
||
|
|
avg(valueOne) as value
|
||
|
|
FROM
|
||
|
|
metric_values
|
||
|
|
WHERE
|
||
|
|
time >= DATEADD(s, @from, '1970-01-01') AND time <= DATEADD(s, @to, '1970-01-01')
|
||
|
|
GROUP BY
|
||
|
|
cast(cast(DATEDIFF(second, {d '1970-01-01'}, DATEADD(second, DATEDIFF(second,GETDATE(),GETUTCDATE()), time))/600 as int)*600 as int),
|
||
|
|
measurement
|
||
|
|
UNION ALL
|
||
|
|
SELECT
|
||
|
|
cast(cast(DATEDIFF(second, {d '1970-01-01'}, DATEADD(second, DATEDIFF(second,GETDATE(),GETUTCDATE()), time))/600 as int)*600 as int) as time,
|
||
|
|
measurement + ' - value two' as metric,
|
||
|
|
avg(valueTwo) as value
|
||
|
|
FROM
|
||
|
|
metric_values
|
||
|
|
WHERE
|
||
|
|
time >= DATEADD(s, @from, '1970-01-01') AND time <= DATEADD(s, @to, '1970-01-01')
|
||
|
|
GROUP BY
|
||
|
|
cast(cast(DATEDIFF(second, {d '1970-01-01'}, DATEADD(second, DATEDIFF(second,GETDATE(),GETUTCDATE()), time))/600 as int)*600 as int),
|
||
|
|
measurement
|
||
|
|
ORDER BY 1
|
||
|
|
END
|
||
|
|
```
|
||
|
|
|
||
|
|
Then we can use the following query for our graph panel.
|
||
|
|
|
||
|
|
```sql
|
||
|
|
DECLARE
|
||
|
|
@from int = $__unixEpochFrom(),
|
||
|
|
@to int = $__unixEpochTo()
|
||
|
|
|
||
|
|
EXEC dbo.sp_test_epoch @from, @to
|
||
|
|
```
|
||
|
|
|
||
|
|
#### Stored procedure using time in datetime format
|
||
|
8 years ago
|
|
||
|
8 years ago
|
We can define a stored procedure that will return all data we need to render 4 series in a graph panel like above.
|
||
|
|
In this case the stored procedure accepts two parameters `@from` and `@to` of `datetime` data types which should be a timerange (from-to)
|
||
|
|
which will be used to filter the data to return from the stored procedure.
|
||
|
|
|
||
|
|
We're mimicking the `$__timeGroup(time, '5m')` in the select and group by expressions and that's why there's a lot of lengthy expressions needed -
|
||
|
|
these could be extracted to MSSQL functions, if wanted.
|
||
|
|
|
||
|
|
```sql
|
||
|
|
CREATE PROCEDURE sp_test_datetime(
|
||
|
|
@from datetime,
|
||
|
|
@to datetime
|
||
|
|
) AS
|
||
|
|
BEGIN
|
||
|
|
SELECT
|
||
|
|
cast(cast(DATEDIFF(second, {d '1970-01-01'}, time)/600 as int)*600 as int) as time,
|
||
|
|
measurement + ' - value one' as metric,
|
||
|
|
avg(valueOne) as value
|
||
|
|
FROM
|
||
|
|
metric_values
|
||
|
|
WHERE
|
||
|
|
time >= @from AND time <= @to
|
||
|
|
GROUP BY
|
||
|
|
cast(cast(DATEDIFF(second, {d '1970-01-01'}, time)/600 as int)*600 as int),
|
||
|
|
measurement
|
||
|
|
UNION ALL
|
||
|
|
SELECT
|
||
|
|
cast(cast(DATEDIFF(second, {d '1970-01-01'}, time)/600 as int)*600 as int) as time,
|
||
|
|
measurement + ' - value two' as metric,
|
||
|
|
avg(valueTwo) as value
|
||
|
|
FROM
|
||
|
|
metric_values
|
||
|
|
WHERE
|
||
|
|
time >= @from AND time <= @to
|
||
|
|
GROUP BY
|
||
|
|
cast(cast(DATEDIFF(second, {d '1970-01-01'}, time)/600 as int)*600 as int),
|
||
|
|
measurement
|
||
|
|
ORDER BY 1
|
||
|
|
END
|
||
|
|
|
||
|
|
```
|
||
|
|
|
||
|
|
Then we can use the following query for our graph panel.
|
||
|
|
|
||
|
|
```sql
|
||
|
|
DECLARE
|
||
|
|
@from datetime = $__timeFrom(),
|
||
|
|
@to datetime = $__timeTo()
|
||
|
|
|
||
|
|
EXEC dbo.sp_test_datetime @from, @to
|
||
|
|
```
|
||
|
8 years ago
|
|
||
|
|
## Alerting
|
||
|
|
|
||
|
8 years ago
|
Time series queries should work in alerting conditions. Table formatted queries are not yet supported in alert rule
|
||
|
8 years ago
|
conditions.
|
||
|
8 years ago
|
|
||
|
6 years ago
|
## Configure the data source with provisioning
|
||
|
8 years ago
|
|
||
|
5 years ago
|
It's now possible to configure data sources using config files with Grafana's provisioning system. You can read more about how it works and all the settings you can set for data sources on the [provisioning docs page]({{< relref "../administration/provisioning/#datasources" >}})
|
||
|
8 years ago
|
|
||
|
6 years ago
|
Here are some provisioning examples for this data source.
|
||
|
8 years ago
|
|
||
|
|
```yaml
|
||
|
|
apiVersion: 1
|
||
|
|
|
||
|
|
datasources:
|
||
|
|
- name: MSSQL
|
||
|
|
type: mssql
|
||
|
|
url: localhost:1433
|
||
|
|
database: grafana
|
||
|
|
user: grafana
|
||
|
7 years ago
|
jsonData:
|
||
|
7 years ago
|
maxOpenConns: 0 # Grafana v5.4+
|
||
|
|
maxIdleConns: 2 # Grafana v5.4+
|
||
|
|
connMaxLifetime: 14400 # Grafana v5.4+
|
||
|
8 years ago
|
secureJsonData:
|
||
|
|
password: "Password!"
|
||
|
|
|
||
|
|
```
|