From 41b5dae606b834b29f218be5ab727e7985897c9d Mon Sep 17 00:00:00 2001 From: Marcus Efraimsson Date: Thu, 30 Aug 2018 16:52:12 +0200 Subject: [PATCH 01/15] start implementing mysql query editor as a copy of postgres query editor --- .../plugins/datasource/mysql/meta_query.ts | 139 +++++ .../plugins/datasource/mysql/mysql_query.ts | 285 +++++++++ .../mysql/partials/query.editor.html | 106 +++- .../plugins/datasource/mysql/query_ctrl.ts | 570 +++++++++++++++++- .../app/plugins/datasource/mysql/sql_part.ts | 86 +++ 5 files changed, 1168 insertions(+), 18 deletions(-) create mode 100644 public/app/plugins/datasource/mysql/meta_query.ts create mode 100644 public/app/plugins/datasource/mysql/mysql_query.ts create mode 100644 public/app/plugins/datasource/mysql/sql_part.ts diff --git a/public/app/plugins/datasource/mysql/meta_query.ts b/public/app/plugins/datasource/mysql/meta_query.ts new file mode 100644 index 00000000000..94e3e8fc3d6 --- /dev/null +++ b/public/app/plugins/datasource/mysql/meta_query.ts @@ -0,0 +1,139 @@ +export class MysqlMetaQuery { + constructor(private target, private queryModel) {} + + getOperators(datatype: string) { + switch (datatype) { + case 'float4': + case 'float8': { + return ['=', '!=', '<', '<=', '>', '>=']; + } + case 'text': + case 'varchar': + case 'char': { + return ['=', '!=', '<', '<=', '>', '>=', 'IN', 'NOT IN', 'LIKE', 'NOT LIKE', '~', '~*', '!~', '!~*']; + } + default: { + return ['=', '!=', '<', '<=', '>', '>=', 'IN', 'NOT IN']; + } + } + } + + // quote identifier as literal to use in metadata queries + quoteIdentAsLiteral(value) { + return this.queryModel.quoteLiteral(this.queryModel.unquoteIdentifier(value)); + } + + findMetricTable() { + // query that returns first table found that has a timestamp(tz) column and a float column + let query = ` + SELECT + table_name as table_name, + ( SELECT + column_name as column_name + FROM information_schema.columns c + WHERE + c.table_schema = t.table_schema AND + c.table_name = t.table_name AND + c.data_type IN ('timestamp', 'datetime') + ORDER BY ordinal_position LIMIT 1 + ) AS time_column, + ( SELECT + column_name AS column_name + FROM information_schema.columns c + WHERE + c.table_schema = t.table_schema AND + c.table_name = t.table_name AND + c.data_type IN('float', 'int', 'bigint') + ORDER BY ordinal_position LIMIT 1 + ) AS value_column + FROM information_schema.tables t + WHERE + EXISTS + ( SELECT 1 + FROM information_schema.columns c + WHERE + c.table_schema = t.table_schema AND + c.table_name = t.table_name AND + c.data_type IN ('timestamp', 'datetime') + ) AND + EXISTS + ( SELECT 1 + FROM information_schema.columns c + WHERE + c.table_schema = t.table_schema AND + c.table_name = t.table_name AND + c.data_type IN('float', 'int', 'bigint') + ) + LIMIT 1 +;`; + return query; + } + + buildTableConstraint(table: string) { + let query = ''; + + // check for schema qualified table + if (table.includes('.')) { + let parts = table.split('.'); + query = 'table_schema = ' + this.quoteIdentAsLiteral(parts[0]); + query += ' AND table_name = ' + this.quoteIdentAsLiteral(parts[1]); + return query; + } else { + query = ' table_name = ' + this.quoteIdentAsLiteral(table); + + return query; + } + } + + buildTableQuery() { + return 'SELECT table_name FROM information_schema.tables ORDER BY table_name'; + } + + buildColumnQuery(type?: string) { + let query = 'SELECT column_name FROM information_schema.columns WHERE '; + query += this.buildTableConstraint(this.target.table); + + switch (type) { + case 'time': { + query += " AND data_type IN ('timestamp','datetime','bigint','int','float')"; + break; + } + case 'metric': { + query += " AND data_type IN ('text' 'tinytext','mediumtext', 'longtext', 'varchar')"; + break; + } + case 'value': { + query += + " AND data_type IN ('bigint','int','float','smallint', 'mediumint', 'tinyint', 'double', 'decimal', 'float')"; + query += ' AND column_name <> ' + this.quoteIdentAsLiteral(this.target.timeColumn); + break; + } + case 'group': { + query += " AND data_type IN ('text' 'tinytext','mediumtext', 'longtext', 'varchar')"; + break; + } + } + + query += ' ORDER BY column_name'; + + return query; + } + + buildValueQuery(column: string) { + let query = 'SELECT DISTINCT QUOTE(' + column + ')'; + query += ' FROM ' + this.target.table; + query += ' WHERE $__timeFilter(' + this.target.timeColumn + ')'; + query += ' ORDER BY 1 LIMIT 100'; + return query; + } + + buildDatatypeQuery(column: string) { + let query = ` +SELECT data_type +FROM information_schema.columns +WHERE `; + query += ' table_name = ' + this.quoteIdentAsLiteral(this.target.table); + query += ' AND column_name = ' + this.quoteIdentAsLiteral(column); + return query; + } +} diff --git a/public/app/plugins/datasource/mysql/mysql_query.ts b/public/app/plugins/datasource/mysql/mysql_query.ts new file mode 100644 index 00000000000..1c4b927ceea --- /dev/null +++ b/public/app/plugins/datasource/mysql/mysql_query.ts @@ -0,0 +1,285 @@ +import _ from 'lodash'; + +export default class MysqlQuery { + target: any; + templateSrv: any; + scopedVars: any; + + /** @ngInject */ + constructor(target, templateSrv?, scopedVars?) { + this.target = target; + this.templateSrv = templateSrv; + this.scopedVars = scopedVars; + + target.format = target.format || 'time_series'; + target.timeColumn = target.timeColumn || 'time'; + target.metricColumn = target.metricColumn || 'none'; + + target.group = target.group || []; + target.where = target.where || [{ type: 'macro', name: '$__timeFilter', params: [] }]; + target.select = target.select || [[{ type: 'column', params: ['value'] }]]; + + // handle pre query gui panels gracefully + if (!('rawQuery' in this.target)) { + if ('rawSql' in target) { + // pre query gui panel + target.rawQuery = true; + } else { + // new panel + target.rawQuery = false; + } + } + + // give interpolateQueryStr access to this + this.interpolateQueryStr = this.interpolateQueryStr.bind(this); + } + + // remove identifier quoting from identifier to use in metadata queries + unquoteIdentifier(value) { + if (value[0] === '"' && value[value.length - 1] === '"') { + return value.substring(1, value.length - 1).replace(/""/g, '"'); + } else { + return value; + } + } + + quoteIdentifier(value) { + return '"' + value.replace(/"/g, '""') + '"'; + } + + quoteLiteral(value) { + return "'" + value.replace(/'/g, "''") + "'"; + } + + escapeLiteral(value) { + return value.replace(/'/g, "''"); + } + + hasTimeGroup() { + return _.find(this.target.group, (g: any) => g.type === 'time'); + } + + hasMetricColumn() { + return this.target.metricColumn !== 'none'; + } + + interpolateQueryStr(value, variable, defaultFormatFn) { + // if no multi or include all do not regexEscape + if (!variable.multi && !variable.includeAll) { + return this.escapeLiteral(value); + } + + if (typeof value === 'string') { + return this.quoteLiteral(value); + } + + let escapedValues = _.map(value, this.quoteLiteral); + return escapedValues.join(','); + } + + render(interpolate?) { + let target = this.target; + + // new query with no table set yet + if (!this.target.rawQuery && !('table' in this.target)) { + return ''; + } + + if (!target.rawQuery) { + target.rawSql = this.buildQuery(); + } + + if (interpolate) { + return this.templateSrv.replace(target.rawSql, this.scopedVars, this.interpolateQueryStr); + } else { + return target.rawSql; + } + } + + hasUnixEpochTimecolumn() { + return ['int4', 'int8', 'float4', 'float8', 'numeric'].indexOf(this.target.timeColumnType) > -1; + } + + buildTimeColumn(alias = true) { + let timeGroup = this.hasTimeGroup(); + let query; + let macro = '$__timeGroup'; + + if (timeGroup) { + let args; + if (timeGroup.params.length > 1 && timeGroup.params[1] !== 'none') { + args = timeGroup.params.join(','); + } else { + args = timeGroup.params[0]; + } + if (this.hasUnixEpochTimecolumn()) { + macro = '$__unixEpochGroup'; + } + if (alias) { + macro += 'Alias'; + } + query = macro + '(' + this.target.timeColumn + ',' + args + ')'; + } else { + query = this.target.timeColumn; + if (alias) { + query += ' AS "time"'; + } + } + + return query; + } + + buildMetricColumn() { + if (this.hasMetricColumn()) { + return this.target.metricColumn + ' AS metric'; + } + + return ''; + } + + buildValueColumns() { + let query = ''; + for (let column of this.target.select) { + query += ',\n ' + this.buildValueColumn(column); + } + + return query; + } + + buildValueColumn(column) { + let query = ''; + + let columnName = _.find(column, (g: any) => g.type === 'column'); + query = columnName.params[0]; + + let aggregate = _.find(column, (g: any) => g.type === 'aggregate' || g.type === 'percentile'); + let windows = _.find(column, (g: any) => g.type === 'window' || g.type === 'moving_window'); + + if (aggregate) { + let func = aggregate.params[0]; + switch (aggregate.type) { + case 'aggregate': + if (func === 'first' || func === 'last') { + query = func + '(' + query + ',' + this.target.timeColumn + ')'; + } else { + query = func + '(' + query + ')'; + } + break; + case 'percentile': + query = func + '(' + aggregate.params[1] + ') WITHIN GROUP (ORDER BY ' + query + ')'; + break; + } + } + + if (windows) { + let overParts = []; + if (this.hasMetricColumn()) { + overParts.push('PARTITION BY ' + this.target.metricColumn); + } + overParts.push('ORDER BY ' + this.buildTimeColumn(false)); + + let over = overParts.join(' '); + let curr: string; + let prev: string; + switch (windows.type) { + case 'window': + switch (windows.params[0]) { + case 'increase': + curr = query; + prev = 'lag(' + curr + ') OVER (' + over + ')'; + query = '(CASE WHEN ' + curr + ' >= ' + prev + ' THEN ' + curr + ' - ' + prev + ' ELSE ' + curr + ' END)'; + break; + case 'rate': + let timeColumn = this.target.timeColumn; + if (aggregate) { + timeColumn = 'min(' + timeColumn + ')'; + } + + curr = query; + prev = 'lag(' + curr + ') OVER (' + over + ')'; + query = '(CASE WHEN ' + curr + ' >= ' + prev + ' THEN ' + curr + ' - ' + prev + ' ELSE ' + curr + ' END)'; + query += '/extract(epoch from ' + timeColumn + ' - lag(' + timeColumn + ') OVER (' + over + '))'; + break; + default: + query = windows.params[0] + '(' + query + ') OVER (' + over + ')'; + break; + } + break; + case 'moving_window': + query = windows.params[0] + '(' + query + ') OVER (' + over + ' ROWS ' + windows.params[1] + ' PRECEDING)'; + break; + } + } + + let alias = _.find(column, (g: any) => g.type === 'alias'); + if (alias) { + query += ' AS ' + this.quoteIdentifier(alias.params[0]); + } + + return query; + } + + buildWhereClause() { + let query = ''; + let conditions = _.map(this.target.where, (tag, index) => { + switch (tag.type) { + case 'macro': + return tag.name + '(' + this.target.timeColumn + ')'; + break; + case 'expression': + return tag.params.join(' '); + break; + } + }); + + if (conditions.length > 0) { + query = '\nWHERE\n ' + conditions.join(' AND\n '); + } + + return query; + } + + buildGroupClause() { + let query = ''; + let groupSection = ''; + + for (let i = 0; i < this.target.group.length; i++) { + let part = this.target.group[i]; + if (i > 0) { + groupSection += ', '; + } + if (part.type === 'time') { + groupSection += '1'; + } else { + groupSection += part.params[0]; + } + } + + if (groupSection.length) { + query = '\nGROUP BY ' + groupSection; + if (this.hasMetricColumn()) { + query += ',2'; + } + } + return query; + } + + buildQuery() { + let query = 'SELECT'; + + query += '\n ' + this.buildTimeColumn(); + if (this.hasMetricColumn()) { + query += ',\n ' + this.buildMetricColumn(); + } + query += this.buildValueColumns(); + + query += '\nFROM ' + this.target.table; + + query += this.buildWhereClause(); + query += this.buildGroupClause(); + + query += '\nORDER BY 1'; + + return query; + } +} diff --git a/public/app/plugins/datasource/mysql/partials/query.editor.html b/public/app/plugins/datasource/mysql/partials/query.editor.html index 1e829a1175d..0c630947657 100644 --- a/public/app/plugins/datasource/mysql/partials/query.editor.html +++ b/public/app/plugins/datasource/mysql/partials/query.editor.html @@ -1,10 +1,102 @@ - -
-
- - -
-
+ + +
+
+
+ + +
+
+
+ +
+
+
+ + + + + + + + +
+ +
+
+
+ +
+ +
+
+ +
+ +
+ + +
+ +
+ +
+ +
+
+
+
+ +
+
+ +
+ +
+ + +
+ +
+ +
+ +
+
+
+ +
+ +
+
+ + + + +
+ +
+ +
+ +
+
+
+
+ +
diff --git a/public/app/plugins/datasource/mysql/query_ctrl.ts b/public/app/plugins/datasource/mysql/query_ctrl.ts index 1de1fb768ad..1c911368ed8 100644 --- a/public/app/plugins/datasource/mysql/query_ctrl.ts +++ b/public/app/plugins/datasource/mysql/query_ctrl.ts @@ -1,12 +1,10 @@ import _ from 'lodash'; +import appEvents from 'app/core/app_events'; +import { MysqlMetaQuery } from './meta_query'; import { QueryCtrl } from 'app/plugins/sdk'; - -export interface MysqlQuery { - refId: string; - format: string; - alias: string; - rawSql: string; -} +import { SqlPart } from 'app/core/components/sql_part/sql_part'; +import MysqlQuery from './mysql_query'; +import sqlPart from './sql_part'; export interface QueryMeta { sql: string; @@ -26,17 +24,31 @@ export class MysqlQueryCtrl extends QueryCtrl { showLastQuerySQL: boolean; formats: any[]; - target: MysqlQuery; lastQueryMeta: QueryMeta; lastQueryError: string; showHelp: boolean; + queryModel: MysqlQuery; + metaBuilder: MysqlMetaQuery; + tableSegment: any; + whereAdd: any; + timeColumnSegment: any; + metricColumnSegment: any; + selectMenu: any[]; + selectParts: SqlPart[][]; + groupParts: SqlPart[]; + whereParts: SqlPart[]; + groupAdd: any; + /** @ngInject **/ - constructor($scope, $injector) { + constructor($scope, $injector, private templateSrv, private $q, private uiSegmentSrv) { super($scope, $injector); - this.target.format = this.target.format || 'time_series'; - this.target.alias = ''; + this.target = this.target; + this.queryModel = new MysqlQuery(this.target, templateSrv, this.panel.scopedVars); + this.metaBuilder = new MysqlMetaQuery(this.target, this.queryModel); + this.updateProjection(); + this.formats = [{ text: 'Time series', value: 'time_series' }, { text: 'Table', value: 'table' }]; if (!this.target.rawSql) { @@ -44,15 +56,199 @@ export class MysqlQueryCtrl extends QueryCtrl { if (this.panelCtrl.panel.type === 'table') { this.target.format = 'table'; this.target.rawSql = 'SELECT 1'; + this.target.rawQuery = true; } else { this.target.rawSql = defaultQuery; + this.datasource.metricFindQuery(this.metaBuilder.findMetricTable()).then(result => { + if (result.length > 0) { + this.target.table = result[0].text; + let segment = this.uiSegmentSrv.newSegment(this.target.table); + this.tableSegment.html = segment.html; + this.tableSegment.value = segment.value; + + this.target.timeColumn = result[1].text; + segment = this.uiSegmentSrv.newSegment(this.target.timeColumn); + this.timeColumnSegment.html = segment.html; + this.timeColumnSegment.value = segment.value; + + this.target.timeColumnType = 'timestamp'; + this.target.select = [[{ type: 'column', params: [result[2].text] }]]; + this.updateProjection(); + this.panelCtrl.refresh(); + } + }); } } + if (!this.target.table) { + this.tableSegment = uiSegmentSrv.newSegment({ value: 'select table', fake: true }); + } else { + this.tableSegment = uiSegmentSrv.newSegment(this.target.table); + } + + this.timeColumnSegment = uiSegmentSrv.newSegment(this.target.timeColumn); + this.metricColumnSegment = uiSegmentSrv.newSegment(this.target.metricColumn); + + this.buildSelectMenu(); + this.whereAdd = this.uiSegmentSrv.newPlusButton(); + this.groupAdd = this.uiSegmentSrv.newPlusButton(); + this.panelCtrl.events.on('data-received', this.onDataReceived.bind(this), $scope); this.panelCtrl.events.on('data-error', this.onDataError.bind(this), $scope); } + updateProjection() { + this.selectParts = _.map(this.target.select, function(parts: any) { + return _.map(parts, sqlPart.create).filter(n => n); + }); + this.whereParts = _.map(this.target.where, sqlPart.create).filter(n => n); + this.groupParts = _.map(this.target.group, sqlPart.create).filter(n => n); + } + + updatePersistedParts() { + this.target.select = _.map(this.selectParts, function(selectParts) { + return _.map(selectParts, function(part: any) { + return { type: part.def.type, datatype: part.datatype, params: part.params }; + }); + }); + this.target.where = _.map(this.whereParts, function(part: any) { + return { type: part.def.type, datatype: part.datatype, name: part.name, params: part.params }; + }); + this.target.group = _.map(this.groupParts, function(part: any) { + return { type: part.def.type, datatype: part.datatype, params: part.params }; + }); + } + + buildSelectMenu() { + this.selectMenu = []; + let aggregates = { + text: 'Aggregate Functions', + value: 'aggregate', + submenu: [ + { text: 'Average', value: 'avg' }, + { text: 'Count', value: 'count' }, + { text: 'Maximum', value: 'max' }, + { text: 'Minimum', value: 'min' }, + { text: 'Sum', value: 'sum' }, + { text: 'Standard deviation', value: 'stddev' }, + { text: 'Variance', value: 'variance' }, + ], + }; + + this.selectMenu.push(aggregates); + this.selectMenu.push({ text: 'Alias', value: 'alias' }); + this.selectMenu.push({ text: 'Column', value: 'column' }); + } + + toggleEditorMode() { + if (this.target.rawQuery) { + appEvents.emit('confirm-modal', { + title: 'Warning', + text2: 'Switching to query builder may overwrite your raw SQL.', + icon: 'fa-exclamation', + yesText: 'Switch', + onConfirm: () => { + this.target.rawQuery = !this.target.rawQuery; + }, + }); + } else { + this.target.rawQuery = !this.target.rawQuery; + } + } + + resetPlusButton(button) { + let plusButton = this.uiSegmentSrv.newPlusButton(); + button.html = plusButton.html; + button.value = plusButton.value; + } + + getTableSegments() { + return this.datasource + .metricFindQuery(this.metaBuilder.buildTableQuery()) + .then(this.transformToSegments({})) + .catch(this.handleQueryError.bind(this)); + } + + tableChanged() { + this.target.table = this.tableSegment.value; + this.target.where = []; + this.target.group = []; + this.updateProjection(); + + let segment = this.uiSegmentSrv.newSegment('none'); + this.metricColumnSegment.html = segment.html; + this.metricColumnSegment.value = segment.value; + this.target.metricColumn = 'none'; + + let task1 = this.datasource.metricFindQuery(this.metaBuilder.buildColumnQuery('time')).then(result => { + // check if time column is still valid + if (result.length > 0 && !_.find(result, (r: any) => r.text === this.target.timeColumn)) { + let segment = this.uiSegmentSrv.newSegment(result[0].text); + this.timeColumnSegment.html = segment.html; + this.timeColumnSegment.value = segment.value; + } + return this.timeColumnChanged(false); + }); + let task2 = this.datasource.metricFindQuery(this.metaBuilder.buildColumnQuery('value')).then(result => { + if (result.length > 0) { + this.target.select = [[{ type: 'column', params: [result[0].text] }]]; + this.updateProjection(); + } + }); + + this.$q.all([task1, task2]).then(() => { + this.panelCtrl.refresh(); + }); + } + + getTimeColumnSegments() { + return this.datasource + .metricFindQuery(this.metaBuilder.buildColumnQuery('time')) + .then(this.transformToSegments({})) + .catch(this.handleQueryError.bind(this)); + } + + timeColumnChanged(refresh?: boolean) { + this.target.timeColumn = this.timeColumnSegment.value; + return this.datasource.metricFindQuery(this.metaBuilder.buildDatatypeQuery(this.target.timeColumn)).then(result => { + if (result.length === 1) { + if (this.target.timeColumnType !== result[0].text) { + this.target.timeColumnType = result[0].text; + } + let partModel; + if (this.queryModel.hasUnixEpochTimecolumn()) { + partModel = sqlPart.create({ type: 'macro', name: '$__unixEpochFilter', params: [] }); + } else { + partModel = sqlPart.create({ type: 'macro', name: '$__timeFilter', params: [] }); + } + + if (this.whereParts.length >= 1 && this.whereParts[0].def.type === 'macro') { + // replace current macro + this.whereParts[0] = partModel; + } else { + this.whereParts.splice(0, 0, partModel); + } + } + + this.updatePersistedParts(); + if (refresh !== false) { + this.panelCtrl.refresh(); + } + }); + } + + getMetricColumnSegments() { + return this.datasource + .metricFindQuery(this.metaBuilder.buildColumnQuery('metric')) + .then(this.transformToSegments({ addNone: true })) + .catch(this.handleQueryError.bind(this)); + } + + metricColumnChanged() { + this.target.metricColumn = this.metricColumnSegment.value; + this.panelCtrl.refresh(); + } + onDataReceived(dataList) { this.lastQueryMeta = null; this.lastQueryError = null; @@ -72,4 +268,356 @@ export class MysqlQueryCtrl extends QueryCtrl { } } } + + transformToSegments(config) { + return results => { + let segments = _.map(results, segment => { + return this.uiSegmentSrv.newSegment({ + value: segment.text, + expandable: segment.expandable, + }); + }); + + if (config.addTemplateVars) { + for (let variable of this.templateSrv.variables) { + let value; + value = '$' + variable.name; + if (config.templateQuoter && variable.multi === false) { + value = config.templateQuoter(value); + } + + segments.unshift( + this.uiSegmentSrv.newSegment({ + type: 'template', + value: value, + expandable: true, + }) + ); + } + } + + if (config.addNone) { + segments.unshift(this.uiSegmentSrv.newSegment({ type: 'template', value: 'none', expandable: true })); + } + + return segments; + }; + } + + findAggregateIndex(selectParts) { + return _.findIndex(selectParts, (p: any) => p.def.type === 'aggregate' || p.def.type === 'percentile'); + } + + findWindowIndex(selectParts) { + return _.findIndex(selectParts, (p: any) => p.def.type === 'window' || p.def.type === 'moving_window'); + } + + addSelectPart(selectParts, item, subItem) { + let partType = item.value; + if (subItem && subItem.type) { + partType = subItem.type; + } + let partModel = sqlPart.create({ type: partType }); + if (subItem) { + partModel.params[0] = subItem.value; + } + let addAlias = false; + + switch (partType) { + case 'column': + let parts = _.map(selectParts, function(part: any) { + return sqlPart.create({ type: part.def.type, params: _.clone(part.params) }); + }); + this.selectParts.push(parts); + break; + case 'percentile': + case 'aggregate': + // add group by if no group by yet + if (this.target.group.length === 0) { + this.addGroup('time', '$__interval'); + } + let aggIndex = this.findAggregateIndex(selectParts); + if (aggIndex !== -1) { + // replace current aggregation + selectParts[aggIndex] = partModel; + } else { + selectParts.splice(1, 0, partModel); + } + if (!_.find(selectParts, (p: any) => p.def.type === 'alias')) { + addAlias = true; + } + break; + case 'moving_window': + case 'window': + let windowIndex = this.findWindowIndex(selectParts); + if (windowIndex !== -1) { + // replace current window function + selectParts[windowIndex] = partModel; + } else { + let aggIndex = this.findAggregateIndex(selectParts); + if (aggIndex !== -1) { + selectParts.splice(aggIndex + 1, 0, partModel); + } else { + selectParts.splice(1, 0, partModel); + } + } + if (!_.find(selectParts, (p: any) => p.def.type === 'alias')) { + addAlias = true; + } + break; + case 'alias': + addAlias = true; + break; + } + + if (addAlias) { + // set initial alias name to column name + partModel = sqlPart.create({ type: 'alias', params: [selectParts[0].params[0].replace(/"/g, '')] }); + if (selectParts[selectParts.length - 1].def.type === 'alias') { + selectParts[selectParts.length - 1] = partModel; + } else { + selectParts.push(partModel); + } + } + + this.updatePersistedParts(); + this.panelCtrl.refresh(); + } + + removeSelectPart(selectParts, part) { + if (part.def.type === 'column') { + // remove all parts of column unless its last column + if (this.selectParts.length > 1) { + let modelsIndex = _.indexOf(this.selectParts, selectParts); + this.selectParts.splice(modelsIndex, 1); + } + } else { + let partIndex = _.indexOf(selectParts, part); + selectParts.splice(partIndex, 1); + } + + this.updatePersistedParts(); + } + + handleSelectPartEvent(selectParts, part, evt) { + switch (evt.name) { + case 'get-param-options': { + switch (part.def.type) { + // case 'aggregate': + // return this.datasource + // .metricFindQuery(this.metaBuilder.buildAggregateQuery()) + // .then(this.transformToSegments({})) + // .catch(this.handleQueryError.bind(this)); + case 'column': + return this.datasource + .metricFindQuery(this.metaBuilder.buildColumnQuery('value')) + .then(this.transformToSegments({})) + .catch(this.handleQueryError.bind(this)); + } + } + case 'part-param-changed': { + this.updatePersistedParts(); + this.panelCtrl.refresh(); + break; + } + case 'action': { + this.removeSelectPart(selectParts, part); + this.panelCtrl.refresh(); + break; + } + case 'get-part-actions': { + return this.$q.when([{ text: 'Remove', value: 'remove-part' }]); + } + } + } + + handleGroupPartEvent(part, index, evt) { + switch (evt.name) { + case 'get-param-options': { + return this.datasource + .metricFindQuery(this.metaBuilder.buildColumnQuery()) + .then(this.transformToSegments({})) + .catch(this.handleQueryError.bind(this)); + } + case 'part-param-changed': { + this.updatePersistedParts(); + this.panelCtrl.refresh(); + break; + } + case 'action': { + this.removeGroup(part, index); + this.panelCtrl.refresh(); + break; + } + case 'get-part-actions': { + return this.$q.when([{ text: 'Remove', value: 'remove-part' }]); + } + } + } + + addGroup(partType, value) { + let params = [value]; + if (partType === 'time') { + params = ['$__interval', 'none']; + } + let partModel = sqlPart.create({ type: partType, params: params }); + + if (partType === 'time') { + // put timeGroup at start + this.groupParts.splice(0, 0, partModel); + } else { + this.groupParts.push(partModel); + } + + // add aggregates when adding group by + for (let selectParts of this.selectParts) { + if (!selectParts.some(part => part.def.type === 'aggregate')) { + let aggregate = sqlPart.create({ type: 'aggregate', params: ['avg'] }); + selectParts.splice(1, 0, aggregate); + if (!selectParts.some(part => part.def.type === 'alias')) { + let alias = sqlPart.create({ type: 'alias', params: [selectParts[0].part.params[0]] }); + selectParts.push(alias); + } + } + } + + this.updatePersistedParts(); + } + + removeGroup(part, index) { + if (part.def.type === 'time') { + // remove aggregations + this.selectParts = _.map(this.selectParts, (s: any) => { + return _.filter(s, (part: any) => { + if (part.def.type === 'aggregate' || part.def.type === 'percentile') { + return false; + } + return true; + }); + }); + } + + this.groupParts.splice(index, 1); + this.updatePersistedParts(); + } + + handleWherePartEvent(whereParts, part, evt, index) { + switch (evt.name) { + case 'get-param-options': { + switch (evt.param.name) { + case 'left': + return this.datasource + .metricFindQuery(this.metaBuilder.buildColumnQuery()) + .then(this.transformToSegments({})) + .catch(this.handleQueryError.bind(this)); + case 'right': + if (['int4', 'int8', 'float4', 'float8', 'timestamp', 'timestamptz'].indexOf(part.datatype) > -1) { + // don't do value lookups for numerical fields + return this.$q.when([]); + } else { + return this.datasource + .metricFindQuery(this.metaBuilder.buildValueQuery(part.params[0])) + .then( + this.transformToSegments({ + addTemplateVars: true, + templateQuoter: (v: string) => { + return this.queryModel.quoteLiteral(v); + }, + }) + ) + .catch(this.handleQueryError.bind(this)); + } + case 'op': + return this.$q.when(this.uiSegmentSrv.newOperators(this.metaBuilder.getOperators(part.datatype))); + default: + return this.$q.when([]); + } + } + case 'part-param-changed': { + this.updatePersistedParts(); + this.datasource.metricFindQuery(this.metaBuilder.buildDatatypeQuery(part.params[0])).then((d: any) => { + if (d.length === 1) { + part.datatype = d[0].text; + } + }); + this.panelCtrl.refresh(); + break; + } + case 'action': { + // remove element + whereParts.splice(index, 1); + this.updatePersistedParts(); + this.panelCtrl.refresh(); + break; + } + case 'get-part-actions': { + return this.$q.when([{ text: 'Remove', value: 'remove-part' }]); + } + } + } + + getWhereOptions() { + var options = []; + if (this.queryModel.hasUnixEpochTimecolumn()) { + options.push(this.uiSegmentSrv.newSegment({ type: 'macro', value: '$__unixEpochFilter' })); + } else { + options.push(this.uiSegmentSrv.newSegment({ type: 'macro', value: '$__timeFilter' })); + } + options.push(this.uiSegmentSrv.newSegment({ type: 'expression', value: 'Expression' })); + return this.$q.when(options); + } + + addWhereAction(part, index) { + switch (this.whereAdd.type) { + case 'macro': { + let partModel = sqlPart.create({ type: 'macro', name: this.whereAdd.value, params: [] }); + if (this.whereParts.length >= 1 && this.whereParts[0].def.type === 'macro') { + // replace current macro + this.whereParts[0] = partModel; + } else { + this.whereParts.splice(0, 0, partModel); + } + break; + } + default: { + this.whereParts.push(sqlPart.create({ type: 'expression', params: ['value', '=', 'value'] })); + } + } + + this.updatePersistedParts(); + this.resetPlusButton(this.whereAdd); + this.panelCtrl.refresh(); + } + + getGroupOptions() { + return this.datasource + .metricFindQuery(this.metaBuilder.buildColumnQuery('group')) + .then(tags => { + var options = []; + if (!this.queryModel.hasTimeGroup()) { + options.push(this.uiSegmentSrv.newSegment({ type: 'time', value: 'time($__interval,none)' })); + } + for (let tag of tags) { + options.push(this.uiSegmentSrv.newSegment({ type: 'column', value: tag.text })); + } + return options; + }) + .catch(this.handleQueryError.bind(this)); + } + + addGroupAction() { + switch (this.groupAdd.value) { + default: { + this.addGroup(this.groupAdd.type, this.groupAdd.value); + } + } + + this.resetPlusButton(this.groupAdd); + this.panelCtrl.refresh(); + } + + handleQueryError(err) { + this.error = err.message || 'Failed to issue metric query'; + return []; + } } diff --git a/public/app/plugins/datasource/mysql/sql_part.ts b/public/app/plugins/datasource/mysql/sql_part.ts new file mode 100644 index 00000000000..25cdd09baa6 --- /dev/null +++ b/public/app/plugins/datasource/mysql/sql_part.ts @@ -0,0 +1,86 @@ +import { SqlPartDef, SqlPart } from 'app/core/components/sql_part/sql_part'; + +let index = []; + +function createPart(part): any { + let def = index[part.type]; + if (!def) { + return null; + } + + return new SqlPart(part, def); +} + +function register(options: any) { + index[options.type] = new SqlPartDef(options); +} + +register({ + type: 'column', + style: 'label', + params: [{ type: 'column', dynamicLookup: true }], + defaultParams: ['value'], +}); + +register({ + type: 'expression', + style: 'expression', + label: 'Expr:', + params: [ + { name: 'left', type: 'string', dynamicLookup: true }, + { name: 'op', type: 'string', dynamicLookup: true }, + { name: 'right', type: 'string', dynamicLookup: true }, + ], + defaultParams: ['value', '=', 'value'], +}); + +register({ + type: 'macro', + style: 'label', + label: 'Macro:', + params: [], + defaultParams: [], +}); + +register({ + type: 'aggregate', + style: 'label', + params: [ + { + name: 'name', + type: 'string', + options: ['avg', 'count', 'min', 'max', 'sum', 'stddev', 'variance'], + }, + ], + defaultParams: ['avg'], +}); + +register({ + type: 'alias', + style: 'label', + params: [{ name: 'name', type: 'string', quote: 'double' }], + defaultParams: ['alias'], +}); + +register({ + type: 'time', + style: 'function', + label: 'time', + params: [ + { + name: 'interval', + type: 'interval', + options: ['$__interval', '1s', '10s', '1m', '5m', '10m', '15m', '1h'], + }, + { + name: 'fill', + type: 'string', + options: ['none', 'NULL', 'previous', '0'], + }, + ], + defaultParams: ['$__interval', 'none'], +}); + +export default { + create: createPart, +}; From 390472aa99ce631dc7f9cf37cb2c8dfea643a827 Mon Sep 17 00:00:00 2001 From: Sven Klemm Date: Fri, 31 Aug 2018 15:40:58 +0200 Subject: [PATCH 02/15] render query from query builder --- .../app/plugins/datasource/mysql/datasource.ts | 17 +++++++++++------ 1 file changed, 11 insertions(+), 6 deletions(-) diff --git a/public/app/plugins/datasource/mysql/datasource.ts b/public/app/plugins/datasource/mysql/datasource.ts index e41417e155c..612ab9adb6c 100644 --- a/public/app/plugins/datasource/mysql/datasource.ts +++ b/public/app/plugins/datasource/mysql/datasource.ts @@ -1,16 +1,19 @@ import _ from 'lodash'; import ResponseParser from './response_parser'; +import MysqlQuery from 'app/plugins/datasource/mysql/mysql_query'; export class MysqlDatasource { id: any; name: any; responseParser: ResponseParser; + queryModel: MysqlQuery; /** @ngInject **/ constructor(instanceSettings, private backendSrv, private $q, private templateSrv) { this.name = instanceSettings.name; this.id = instanceSettings.id; this.responseParser = new ResponseParser(this.$q); + this.queryModel = new MysqlQuery({}); } interpolateVariable(value, variable) { @@ -37,16 +40,18 @@ export class MysqlDatasource { } query(options) { - const queries = _.filter(options.targets, item => { - return item.hide !== true; - }).map(item => { + const queries = _.filter(options.targets, target => { + return target.hide !== true; + }).map(target => { + let queryModel = new MysqlQuery(target, this.templateSrv, options.scopedVars); + return { - refId: item.refId, + refId: target.refId, intervalMs: options.intervalMs, maxDataPoints: options.maxDataPoints, datasourceId: this.id, - rawSql: this.templateSrv.replace(item.rawSql, options.scopedVars, this.interpolateVariable), - format: item.format, + rawSql: queryModel.render(this.interpolateVariable), + format: target.format, }; }); From 8d73f53e973fbf0cd014c8d0965bd31f9f086140 Mon Sep 17 00:00:00 2001 From: Sven Klemm Date: Fri, 31 Aug 2018 16:27:48 +0200 Subject: [PATCH 03/15] use quoting functions from MysqlQuery in datasource --- public/app/plugins/datasource/mysql/datasource.ts | 10 +++------- 1 file changed, 3 insertions(+), 7 deletions(-) diff --git a/public/app/plugins/datasource/mysql/datasource.ts b/public/app/plugins/datasource/mysql/datasource.ts index 612ab9adb6c..d5bd2594f24 100644 --- a/public/app/plugins/datasource/mysql/datasource.ts +++ b/public/app/plugins/datasource/mysql/datasource.ts @@ -19,7 +19,7 @@ export class MysqlDatasource { interpolateVariable(value, variable) { if (typeof value === 'string') { if (variable.multi || variable.includeAll) { - return "'" + value.replace(/'/g, `''`) + "'"; + return this.queryModel.quoteLiteral(value); } else { return value; } @@ -29,12 +29,8 @@ export class MysqlDatasource { return value; } - const quotedValues = _.map(value, function(val) { - if (typeof value === 'number') { - return value; - } - - return "'" + val.replace(/'/g, `''`) + "'"; + const quotedValues = _.map(value, v => { + return this.queryModel.quoteLiteral(v); }); return quotedValues.join(','); } From cd708d6cb2100f8c76c967e9432fda36f5a9f289 Mon Sep 17 00:00:00 2001 From: Sven Klemm Date: Fri, 31 Aug 2018 16:52:26 +0200 Subject: [PATCH 04/15] ignore information_schema tables --- public/app/plugins/datasource/mysql/meta_query.ts | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/public/app/plugins/datasource/mysql/meta_query.ts b/public/app/plugins/datasource/mysql/meta_query.ts index 94e3e8fc3d6..d5383e85ff7 100644 --- a/public/app/plugins/datasource/mysql/meta_query.ts +++ b/public/app/plugins/datasource/mysql/meta_query.ts @@ -86,7 +86,7 @@ export class MysqlMetaQuery { } buildTableQuery() { - return 'SELECT table_name FROM information_schema.tables ORDER BY table_name'; + return "SELECT table_name FROM information_schema.tables WHERE table_schema <> 'information_schema' ORDER BY table_name"; } buildColumnQuery(type?: string) { From bcfb841cb48178b7eb9fc9908e304d47a313a59a Mon Sep 17 00:00:00 2001 From: Sven Klemm Date: Fri, 31 Aug 2018 18:24:09 +0200 Subject: [PATCH 05/15] pass timerange in meta data queries --- public/app/plugins/datasource/mysql/datasource.ts | 5 ++++- .../datasource/mysql/specs/datasource.test.ts | 13 ++++++++++++- 2 files changed, 16 insertions(+), 2 deletions(-) diff --git a/public/app/plugins/datasource/mysql/datasource.ts b/public/app/plugins/datasource/mysql/datasource.ts index d5bd2594f24..7b112ef4336 100644 --- a/public/app/plugins/datasource/mysql/datasource.ts +++ b/public/app/plugins/datasource/mysql/datasource.ts @@ -9,7 +9,7 @@ export class MysqlDatasource { queryModel: MysqlQuery; /** @ngInject **/ - constructor(instanceSettings, private backendSrv, private $q, private templateSrv) { + constructor(instanceSettings, private backendSrv, private $q, private templateSrv, private timeSrv) { this.name = instanceSettings.name; this.id = instanceSettings.id; this.responseParser = new ResponseParser(this.$q); @@ -108,8 +108,11 @@ export class MysqlDatasource { format: 'table', }; + const range = this.timeSrv.timeRange(); const data = { queries: [interpolatedQuery], + from: range.from.valueOf().toString(), + to: range.to.valueOf().toString(), }; if (optionalOptions && optionalOptions.range && optionalOptions.range.from) { diff --git a/public/app/plugins/datasource/mysql/specs/datasource.test.ts b/public/app/plugins/datasource/mysql/specs/datasource.test.ts index e75ba5e32ee..163f3afe671 100644 --- a/public/app/plugins/datasource/mysql/specs/datasource.test.ts +++ b/public/app/plugins/datasource/mysql/specs/datasource.test.ts @@ -9,12 +9,23 @@ describe('MySQLDatasource', function() { replace: jest.fn(text => text), }; + const raw = { + from: moment.utc('2018-04-25 10:00'), + to: moment.utc('2018-04-25 11:00'), + }; const ctx = { backendSrv, + timeSrvMock: { + timeRange: () => ({ + from: raw.from, + to: raw.to, + raw: raw, + }), + }, }; beforeEach(() => { - ctx.ds = new MysqlDatasource(instanceSettings, backendSrv, {}, templateSrv); + ctx.ds = new MysqlDatasource(instanceSettings, backendSrv, {}, templateSrv, ctx.timeSrvMock); }); describe('When performing annotationQuery', function() { From c4452ba335ce5366f799a6e771411510eb3b5150 Mon Sep 17 00:00:00 2001 From: Sven Klemm Date: Thu, 18 Oct 2018 20:01:40 +0200 Subject: [PATCH 06/15] Fix tslint errors --- .../plugins/datasource/mysql/datasource.ts | 4 +- .../plugins/datasource/mysql/meta_query.ts | 4 +- .../plugins/datasource/mysql/mysql_query.ts | 26 ++++----- .../plugins/datasource/mysql/query_ctrl.ts | 56 +++++++++---------- .../datasource/mysql/specs/datasource.test.ts | 4 +- .../app/plugins/datasource/mysql/sql_part.ts | 4 +- 6 files changed, 49 insertions(+), 49 deletions(-) diff --git a/public/app/plugins/datasource/mysql/datasource.ts b/public/app/plugins/datasource/mysql/datasource.ts index 23bee7dbb6e..4b4c3c3a526 100644 --- a/public/app/plugins/datasource/mysql/datasource.ts +++ b/public/app/plugins/datasource/mysql/datasource.ts @@ -9,7 +9,7 @@ export class MysqlDatasource { queryModel: MysqlQuery; interval: string; - /** @ngInject **/ + /** @ngInject */ constructor(instanceSettings, private backendSrv, private $q, private templateSrv, private timeSrv) { this.name = instanceSettings.name; this.id = instanceSettings.id; @@ -41,7 +41,7 @@ export class MysqlDatasource { const queries = _.filter(options.targets, target => { return target.hide !== true; }).map(target => { - let queryModel = new MysqlQuery(target, this.templateSrv, options.scopedVars); + const queryModel = new MysqlQuery(target, this.templateSrv, options.scopedVars); return { refId: target.refId, diff --git a/public/app/plugins/datasource/mysql/meta_query.ts b/public/app/plugins/datasource/mysql/meta_query.ts index d5383e85ff7..21fe490df43 100644 --- a/public/app/plugins/datasource/mysql/meta_query.ts +++ b/public/app/plugins/datasource/mysql/meta_query.ts @@ -25,7 +25,7 @@ export class MysqlMetaQuery { findMetricTable() { // query that returns first table found that has a timestamp(tz) column and a float column - let query = ` + const query = ` SELECT table_name as table_name, ( SELECT @@ -74,7 +74,7 @@ export class MysqlMetaQuery { // check for schema qualified table if (table.includes('.')) { - let parts = table.split('.'); + const parts = table.split('.'); query = 'table_schema = ' + this.quoteIdentAsLiteral(parts[0]); query += ' AND table_name = ' + this.quoteIdentAsLiteral(parts[1]); return query; diff --git a/public/app/plugins/datasource/mysql/mysql_query.ts b/public/app/plugins/datasource/mysql/mysql_query.ts index 1c4b927ceea..e617433dbd3 100644 --- a/public/app/plugins/datasource/mysql/mysql_query.ts +++ b/public/app/plugins/datasource/mysql/mysql_query.ts @@ -73,12 +73,12 @@ export default class MysqlQuery { return this.quoteLiteral(value); } - let escapedValues = _.map(value, this.quoteLiteral); + const escapedValues = _.map(value, this.quoteLiteral); return escapedValues.join(','); } render(interpolate?) { - let target = this.target; + const target = this.target; // new query with no table set yet if (!this.target.rawQuery && !('table' in this.target)) { @@ -101,7 +101,7 @@ export default class MysqlQuery { } buildTimeColumn(alias = true) { - let timeGroup = this.hasTimeGroup(); + const timeGroup = this.hasTimeGroup(); let query; let macro = '$__timeGroup'; @@ -139,7 +139,7 @@ export default class MysqlQuery { buildValueColumns() { let query = ''; - for (let column of this.target.select) { + for (const column of this.target.select) { query += ',\n ' + this.buildValueColumn(column); } @@ -149,14 +149,14 @@ export default class MysqlQuery { buildValueColumn(column) { let query = ''; - let columnName = _.find(column, (g: any) => g.type === 'column'); + const columnName = _.find(column, (g: any) => g.type === 'column'); query = columnName.params[0]; - let aggregate = _.find(column, (g: any) => g.type === 'aggregate' || g.type === 'percentile'); - let windows = _.find(column, (g: any) => g.type === 'window' || g.type === 'moving_window'); + const aggregate = _.find(column, (g: any) => g.type === 'aggregate' || g.type === 'percentile'); + const windows = _.find(column, (g: any) => g.type === 'window' || g.type === 'moving_window'); if (aggregate) { - let func = aggregate.params[0]; + const func = aggregate.params[0]; switch (aggregate.type) { case 'aggregate': if (func === 'first' || func === 'last') { @@ -172,13 +172,13 @@ export default class MysqlQuery { } if (windows) { - let overParts = []; + const overParts = []; if (this.hasMetricColumn()) { overParts.push('PARTITION BY ' + this.target.metricColumn); } overParts.push('ORDER BY ' + this.buildTimeColumn(false)); - let over = overParts.join(' '); + const over = overParts.join(' '); let curr: string; let prev: string; switch (windows.type) { @@ -211,7 +211,7 @@ export default class MysqlQuery { } } - let alias = _.find(column, (g: any) => g.type === 'alias'); + const alias = _.find(column, (g: any) => g.type === 'alias'); if (alias) { query += ' AS ' + this.quoteIdentifier(alias.params[0]); } @@ -221,7 +221,7 @@ export default class MysqlQuery { buildWhereClause() { let query = ''; - let conditions = _.map(this.target.where, (tag, index) => { + const conditions = _.map(this.target.where, (tag, index) => { switch (tag.type) { case 'macro': return tag.name + '(' + this.target.timeColumn + ')'; @@ -244,7 +244,7 @@ export default class MysqlQuery { let groupSection = ''; for (let i = 0; i < this.target.group.length; i++) { - let part = this.target.group[i]; + const part = this.target.group[i]; if (i > 0) { groupSection += ', '; } diff --git a/public/app/plugins/datasource/mysql/query_ctrl.ts b/public/app/plugins/datasource/mysql/query_ctrl.ts index 1c911368ed8..b7520d8a645 100644 --- a/public/app/plugins/datasource/mysql/query_ctrl.ts +++ b/public/app/plugins/datasource/mysql/query_ctrl.ts @@ -40,7 +40,7 @@ export class MysqlQueryCtrl extends QueryCtrl { whereParts: SqlPart[]; groupAdd: any; - /** @ngInject **/ + /** @ngInject */ constructor($scope, $injector, private templateSrv, private $q, private uiSegmentSrv) { super($scope, $injector); @@ -98,7 +98,7 @@ export class MysqlQueryCtrl extends QueryCtrl { } updateProjection() { - this.selectParts = _.map(this.target.select, function(parts: any) { + this.selectParts = _.map(this.target.select, (parts: any) => { return _.map(parts, sqlPart.create).filter(n => n); }); this.whereParts = _.map(this.target.where, sqlPart.create).filter(n => n); @@ -106,22 +106,22 @@ export class MysqlQueryCtrl extends QueryCtrl { } updatePersistedParts() { - this.target.select = _.map(this.selectParts, function(selectParts) { - return _.map(selectParts, function(part: any) { + this.target.select = _.map(this.selectParts, selectParts => { + return _.map(selectParts, (part: any) => { return { type: part.def.type, datatype: part.datatype, params: part.params }; }); }); - this.target.where = _.map(this.whereParts, function(part: any) { + this.target.where = _.map(this.whereParts, (part: any) => { return { type: part.def.type, datatype: part.datatype, name: part.name, params: part.params }; }); - this.target.group = _.map(this.groupParts, function(part: any) { + this.target.group = _.map(this.groupParts, (part: any) => { return { type: part.def.type, datatype: part.datatype, params: part.params }; }); } buildSelectMenu() { this.selectMenu = []; - let aggregates = { + const aggregates = { text: 'Aggregate Functions', value: 'aggregate', submenu: [ @@ -157,7 +157,7 @@ export class MysqlQueryCtrl extends QueryCtrl { } resetPlusButton(button) { - let plusButton = this.uiSegmentSrv.newPlusButton(); + const plusButton = this.uiSegmentSrv.newPlusButton(); button.html = plusButton.html; button.value = plusButton.value; } @@ -175,21 +175,21 @@ export class MysqlQueryCtrl extends QueryCtrl { this.target.group = []; this.updateProjection(); - let segment = this.uiSegmentSrv.newSegment('none'); + const segment = this.uiSegmentSrv.newSegment('none'); this.metricColumnSegment.html = segment.html; this.metricColumnSegment.value = segment.value; this.target.metricColumn = 'none'; - let task1 = this.datasource.metricFindQuery(this.metaBuilder.buildColumnQuery('time')).then(result => { + const task1 = this.datasource.metricFindQuery(this.metaBuilder.buildColumnQuery('time')).then(result => { // check if time column is still valid if (result.length > 0 && !_.find(result, (r: any) => r.text === this.target.timeColumn)) { - let segment = this.uiSegmentSrv.newSegment(result[0].text); + const segment = this.uiSegmentSrv.newSegment(result[0].text); this.timeColumnSegment.html = segment.html; this.timeColumnSegment.value = segment.value; } return this.timeColumnChanged(false); }); - let task2 = this.datasource.metricFindQuery(this.metaBuilder.buildColumnQuery('value')).then(result => { + const task2 = this.datasource.metricFindQuery(this.metaBuilder.buildColumnQuery('value')).then(result => { if (result.length > 0) { this.target.select = [[{ type: 'column', params: [result[0].text] }]]; this.updateProjection(); @@ -271,7 +271,7 @@ export class MysqlQueryCtrl extends QueryCtrl { transformToSegments(config) { return results => { - let segments = _.map(results, segment => { + const segments = _.map(results, segment => { return this.uiSegmentSrv.newSegment({ value: segment.text, expandable: segment.expandable, @@ -279,7 +279,7 @@ export class MysqlQueryCtrl extends QueryCtrl { }); if (config.addTemplateVars) { - for (let variable of this.templateSrv.variables) { + for (const variable of this.templateSrv.variables) { let value; value = '$' + variable.name; if (config.templateQuoter && variable.multi === false) { @@ -325,7 +325,7 @@ export class MysqlQueryCtrl extends QueryCtrl { switch (partType) { case 'column': - let parts = _.map(selectParts, function(part: any) { + const parts = _.map(selectParts, (part: any) => { return sqlPart.create({ type: part.def.type, params: _.clone(part.params) }); }); this.selectParts.push(parts); @@ -336,7 +336,7 @@ export class MysqlQueryCtrl extends QueryCtrl { if (this.target.group.length === 0) { this.addGroup('time', '$__interval'); } - let aggIndex = this.findAggregateIndex(selectParts); + const aggIndex = this.findAggregateIndex(selectParts); if (aggIndex !== -1) { // replace current aggregation selectParts[aggIndex] = partModel; @@ -349,12 +349,12 @@ export class MysqlQueryCtrl extends QueryCtrl { break; case 'moving_window': case 'window': - let windowIndex = this.findWindowIndex(selectParts); + const windowIndex = this.findWindowIndex(selectParts); if (windowIndex !== -1) { // replace current window function selectParts[windowIndex] = partModel; } else { - let aggIndex = this.findAggregateIndex(selectParts); + const aggIndex = this.findAggregateIndex(selectParts); if (aggIndex !== -1) { selectParts.splice(aggIndex + 1, 0, partModel); } else { @@ -388,11 +388,11 @@ export class MysqlQueryCtrl extends QueryCtrl { if (part.def.type === 'column') { // remove all parts of column unless its last column if (this.selectParts.length > 1) { - let modelsIndex = _.indexOf(this.selectParts, selectParts); + const modelsIndex = _.indexOf(this.selectParts, selectParts); this.selectParts.splice(modelsIndex, 1); } } else { - let partIndex = _.indexOf(selectParts, part); + const partIndex = _.indexOf(selectParts, part); selectParts.splice(partIndex, 1); } @@ -460,7 +460,7 @@ export class MysqlQueryCtrl extends QueryCtrl { if (partType === 'time') { params = ['$__interval', 'none']; } - let partModel = sqlPart.create({ type: partType, params: params }); + const partModel = sqlPart.create({ type: partType, params: params }); if (partType === 'time') { // put timeGroup at start @@ -470,12 +470,12 @@ export class MysqlQueryCtrl extends QueryCtrl { } // add aggregates when adding group by - for (let selectParts of this.selectParts) { + for (const selectParts of this.selectParts) { if (!selectParts.some(part => part.def.type === 'aggregate')) { - let aggregate = sqlPart.create({ type: 'aggregate', params: ['avg'] }); + const aggregate = sqlPart.create({ type: 'aggregate', params: ['avg'] }); selectParts.splice(1, 0, aggregate); if (!selectParts.some(part => part.def.type === 'alias')) { - let alias = sqlPart.create({ type: 'alias', params: [selectParts[0].part.params[0]] }); + const alias = sqlPart.create({ type: 'alias', params: [selectParts[0].part.params[0]] }); selectParts.push(alias); } } @@ -557,7 +557,7 @@ export class MysqlQueryCtrl extends QueryCtrl { } getWhereOptions() { - var options = []; + const options = []; if (this.queryModel.hasUnixEpochTimecolumn()) { options.push(this.uiSegmentSrv.newSegment({ type: 'macro', value: '$__unixEpochFilter' })); } else { @@ -570,7 +570,7 @@ export class MysqlQueryCtrl extends QueryCtrl { addWhereAction(part, index) { switch (this.whereAdd.type) { case 'macro': { - let partModel = sqlPart.create({ type: 'macro', name: this.whereAdd.value, params: [] }); + const partModel = sqlPart.create({ type: 'macro', name: this.whereAdd.value, params: [] }); if (this.whereParts.length >= 1 && this.whereParts[0].def.type === 'macro') { // replace current macro this.whereParts[0] = partModel; @@ -593,11 +593,11 @@ export class MysqlQueryCtrl extends QueryCtrl { return this.datasource .metricFindQuery(this.metaBuilder.buildColumnQuery('group')) .then(tags => { - var options = []; + const options = []; if (!this.queryModel.hasTimeGroup()) { options.push(this.uiSegmentSrv.newSegment({ type: 'time', value: 'time($__interval,none)' })); } - for (let tag of tags) { + for (const tag of tags) { options.push(this.uiSegmentSrv.newSegment({ type: 'column', value: tag.text })); } return options; diff --git a/public/app/plugins/datasource/mysql/specs/datasource.test.ts b/public/app/plugins/datasource/mysql/specs/datasource.test.ts index cc1e54ac496..f3fbcd93333 100644 --- a/public/app/plugins/datasource/mysql/specs/datasource.test.ts +++ b/public/app/plugins/datasource/mysql/specs/datasource.test.ts @@ -13,7 +13,7 @@ describe('MySQLDatasource', () => { from: moment.utc('2018-04-25 10:00'), to: moment.utc('2018-04-25 11:00'), }; - const ctx = { + const ctx = { backendSrv, timeSrvMock: { timeRange: () => ({ @@ -22,7 +22,7 @@ describe('MySQLDatasource', () => { raw: raw, }), }, - }; + } as any; beforeEach(() => { ctx.ds = new MysqlDatasource(instanceSettings, backendSrv, {}, templateSrv, ctx.timeSrvMock); diff --git a/public/app/plugins/datasource/mysql/sql_part.ts b/public/app/plugins/datasource/mysql/sql_part.ts index 25cdd09baa6..e7984ef1346 100644 --- a/public/app/plugins/datasource/mysql/sql_part.ts +++ b/public/app/plugins/datasource/mysql/sql_part.ts @@ -1,9 +1,9 @@ import { SqlPartDef, SqlPart } from 'app/core/components/sql_part/sql_part'; -let index = []; +const index = []; function createPart(part): any { - let def = index[part.type]; + const def = index[part.type]; if (!def) { return null; } From 215ca50cc1ec94da9a97609819441b84139e3a08 Mon Sep 17 00:00:00 2001 From: Sven Klemm Date: Fri, 19 Oct 2018 10:19:33 +0200 Subject: [PATCH 07/15] make interpolateVariable arrow function --- public/app/plugins/datasource/mysql/datasource.ts | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/public/app/plugins/datasource/mysql/datasource.ts b/public/app/plugins/datasource/mysql/datasource.ts index 4b4c3c3a526..f0381d53b70 100644 --- a/public/app/plugins/datasource/mysql/datasource.ts +++ b/public/app/plugins/datasource/mysql/datasource.ts @@ -18,7 +18,7 @@ export class MysqlDatasource { this.interval = (instanceSettings.jsonData || {}).timeInterval; } - interpolateVariable(value, variable) { + interpolateVariable = (value, variable) => { if (typeof value === 'string') { if (variable.multi || variable.includeAll) { return this.queryModel.quoteLiteral(value); @@ -35,7 +35,7 @@ export class MysqlDatasource { return this.queryModel.quoteLiteral(v); }); return quotedValues.join(','); - } + }; query(options) { const queries = _.filter(options.targets, target => { From aae21a631eb8356b2a64ebe199d58e5c1684a82c Mon Sep 17 00:00:00 2001 From: Sven Klemm Date: Fri, 19 Oct 2018 14:52:25 +0200 Subject: [PATCH 08/15] fix references to postgres datatypes --- public/app/plugins/datasource/mysql/mysql_query.ts | 2 +- public/app/plugins/datasource/mysql/query_ctrl.ts | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/public/app/plugins/datasource/mysql/mysql_query.ts b/public/app/plugins/datasource/mysql/mysql_query.ts index e617433dbd3..527839ba10c 100644 --- a/public/app/plugins/datasource/mysql/mysql_query.ts +++ b/public/app/plugins/datasource/mysql/mysql_query.ts @@ -97,7 +97,7 @@ export default class MysqlQuery { } hasUnixEpochTimecolumn() { - return ['int4', 'int8', 'float4', 'float8', 'numeric'].indexOf(this.target.timeColumnType) > -1; + return ['int', 'bigint', 'double'].indexOf(this.target.timeColumnType) > -1; } buildTimeColumn(alias = true) { diff --git a/public/app/plugins/datasource/mysql/query_ctrl.ts b/public/app/plugins/datasource/mysql/query_ctrl.ts index b7520d8a645..8161404a126 100644 --- a/public/app/plugins/datasource/mysql/query_ctrl.ts +++ b/public/app/plugins/datasource/mysql/query_ctrl.ts @@ -511,7 +511,7 @@ export class MysqlQueryCtrl extends QueryCtrl { .then(this.transformToSegments({})) .catch(this.handleQueryError.bind(this)); case 'right': - if (['int4', 'int8', 'float4', 'float8', 'timestamp', 'timestamptz'].indexOf(part.datatype) > -1) { + if (['int', 'bigint', 'double', 'datetime'].indexOf(part.datatype) > -1) { // don't do value lookups for numerical fields return this.$q.when([]); } else { From 8ce7e113d995f979f3c90bd1a877570acfa7c46d Mon Sep 17 00:00:00 2001 From: Sven Klemm Date: Fri, 19 Oct 2018 15:05:49 +0200 Subject: [PATCH 09/15] adjust meta data queries for mysql --- public/app/plugins/datasource/mysql/meta_query.ts | 9 ++++----- 1 file changed, 4 insertions(+), 5 deletions(-) diff --git a/public/app/plugins/datasource/mysql/meta_query.ts b/public/app/plugins/datasource/mysql/meta_query.ts index 21fe490df43..32830d20aee 100644 --- a/public/app/plugins/datasource/mysql/meta_query.ts +++ b/public/app/plugins/datasource/mysql/meta_query.ts @@ -79,14 +79,14 @@ export class MysqlMetaQuery { query += ' AND table_name = ' + this.quoteIdentAsLiteral(parts[1]); return query; } else { - query = ' table_name = ' + this.quoteIdentAsLiteral(table); + query = 'table_schema = database() AND table_name = ' + this.quoteIdentAsLiteral(table); return query; } } buildTableQuery() { - return "SELECT table_name FROM information_schema.tables WHERE table_schema <> 'information_schema' ORDER BY table_name"; + return 'SELECT table_name FROM information_schema.tables WHERE table_schema = database() ORDER BY table_name'; } buildColumnQuery(type?: string) { @@ -95,7 +95,7 @@ export class MysqlMetaQuery { switch (type) { case 'time': { - query += " AND data_type IN ('timestamp','datetime','bigint','int','float')"; + query += " AND data_type IN ('timestamp','datetime','bigint','int','double','float')"; break; } case 'metric': { @@ -103,8 +103,7 @@ export class MysqlMetaQuery { break; } case 'value': { - query += - " AND data_type IN ('bigint','int','float','smallint', 'mediumint', 'tinyint', 'double', 'decimal', 'float')"; + query += " AND data_type IN ('bigint','int','smallint','mediumint','tinyint','double','decimal','float')"; query += ' AND column_name <> ' + this.quoteIdentAsLiteral(this.target.timeColumn); break; } From 7c8b4915c18bbe05863b1518dea22bafd9774e5d Mon Sep 17 00:00:00 2001 From: Sven Klemm Date: Fri, 19 Oct 2018 18:23:03 +0200 Subject: [PATCH 10/15] fix order for mysql, remove postgres specific code --- .../plugins/datasource/mysql/mysql_query.ts | 58 +------------------ 1 file changed, 3 insertions(+), 55 deletions(-) diff --git a/public/app/plugins/datasource/mysql/mysql_query.ts b/public/app/plugins/datasource/mysql/mysql_query.ts index 527839ba10c..e636d66e6fd 100644 --- a/public/app/plugins/datasource/mysql/mysql_query.ts +++ b/public/app/plugins/datasource/mysql/mysql_query.ts @@ -152,63 +152,11 @@ export default class MysqlQuery { const columnName = _.find(column, (g: any) => g.type === 'column'); query = columnName.params[0]; - const aggregate = _.find(column, (g: any) => g.type === 'aggregate' || g.type === 'percentile'); - const windows = _.find(column, (g: any) => g.type === 'window' || g.type === 'moving_window'); + const aggregate = _.find(column, (g: any) => g.type === 'aggregate'); if (aggregate) { const func = aggregate.params[0]; - switch (aggregate.type) { - case 'aggregate': - if (func === 'first' || func === 'last') { - query = func + '(' + query + ',' + this.target.timeColumn + ')'; - } else { - query = func + '(' + query + ')'; - } - break; - case 'percentile': - query = func + '(' + aggregate.params[1] + ') WITHIN GROUP (ORDER BY ' + query + ')'; - break; - } - } - - if (windows) { - const overParts = []; - if (this.hasMetricColumn()) { - overParts.push('PARTITION BY ' + this.target.metricColumn); - } - overParts.push('ORDER BY ' + this.buildTimeColumn(false)); - - const over = overParts.join(' '); - let curr: string; - let prev: string; - switch (windows.type) { - case 'window': - switch (windows.params[0]) { - case 'increase': - curr = query; - prev = 'lag(' + curr + ') OVER (' + over + ')'; - query = '(CASE WHEN ' + curr + ' >= ' + prev + ' THEN ' + curr + ' - ' + prev + ' ELSE ' + curr + ' END)'; - break; - case 'rate': - let timeColumn = this.target.timeColumn; - if (aggregate) { - timeColumn = 'min(' + timeColumn + ')'; - } - - curr = query; - prev = 'lag(' + curr + ') OVER (' + over + ')'; - query = '(CASE WHEN ' + curr + ' >= ' + prev + ' THEN ' + curr + ' - ' + prev + ' ELSE ' + curr + ' END)'; - query += '/extract(epoch from ' + timeColumn + ' - lag(' + timeColumn + ') OVER (' + over + '))'; - break; - default: - query = windows.params[0] + '(' + query + ') OVER (' + over + ')'; - break; - } - break; - case 'moving_window': - query = windows.params[0] + '(' + query + ') OVER (' + over + ' ROWS ' + windows.params[1] + ' PRECEDING)'; - break; - } + query = func + '(' + query + ')'; } const alias = _.find(column, (g: any) => g.type === 'alias'); @@ -278,7 +226,7 @@ export default class MysqlQuery { query += this.buildWhereClause(); query += this.buildGroupClause(); - query += '\nORDER BY 1'; + query += '\nORDER BY ' + this.buildTimeColumn(false); return query; } From fdaa153c950e2cbd0db279e456e7c3dc88ae76f5 Mon Sep 17 00:00:00 2001 From: Sven Klemm Date: Tue, 23 Oct 2018 09:51:17 +0200 Subject: [PATCH 11/15] add char as datatype for metric and group columns --- public/app/plugins/datasource/mysql/meta_query.ts | 13 ++++++++----- 1 file changed, 8 insertions(+), 5 deletions(-) diff --git a/public/app/plugins/datasource/mysql/meta_query.ts b/public/app/plugins/datasource/mysql/meta_query.ts index 32830d20aee..9217edb755b 100644 --- a/public/app/plugins/datasource/mysql/meta_query.ts +++ b/public/app/plugins/datasource/mysql/meta_query.ts @@ -3,14 +3,17 @@ export class MysqlMetaQuery { getOperators(datatype: string) { switch (datatype) { - case 'float4': - case 'float8': { + case 'double': + case 'float': { return ['=', '!=', '<', '<=', '>', '>=']; } case 'text': + case 'tinytext': + case 'mediumtext': + case 'longtext': case 'varchar': case 'char': { - return ['=', '!=', '<', '<=', '>', '>=', 'IN', 'NOT IN', 'LIKE', 'NOT LIKE', '~', '~*', '!~', '!~*']; + return ['=', '!=', '<', '<=', '>', '>=', 'IN', 'NOT IN', 'LIKE', 'NOT LIKE']; } default: { return ['=', '!=', '<', '<=', '>', '>=', 'IN', 'NOT IN']; @@ -99,7 +102,7 @@ export class MysqlMetaQuery { break; } case 'metric': { - query += " AND data_type IN ('text' 'tinytext','mediumtext', 'longtext', 'varchar')"; + query += " AND data_type IN ('text','tinytext','mediumtext','longtext','varchar','char')"; break; } case 'value': { @@ -108,7 +111,7 @@ export class MysqlMetaQuery { break; } case 'group': { - query += " AND data_type IN ('text' 'tinytext','mediumtext', 'longtext', 'varchar')"; + query += " AND data_type IN ('text','tinytext','mediumtext','longtext','varchar','char')"; break; } } From 261122ff4b2dcd74c9e263e8dce045c29928056c Mon Sep 17 00:00:00 2001 From: Sven Klemm Date: Tue, 23 Oct 2018 10:04:45 +0200 Subject: [PATCH 12/15] sync mysql query editor template with postgres --- .../mysql/partials/query.editor.html | 60 ++++++++++--------- 1 file changed, 33 insertions(+), 27 deletions(-) diff --git a/public/app/plugins/datasource/mysql/partials/query.editor.html b/public/app/plugins/datasource/mysql/partials/query.editor.html index d01b201b748..f857244b438 100644 --- a/public/app/plugins/datasource/mysql/partials/query.editor.html +++ b/public/app/plugins/datasource/mysql/partials/query.editor.html @@ -100,36 +100,42 @@
- -
- -
-
-
-
+
+ +
+
+ -
-
-
+
+ -
-
-
-
-
+
+
+
+
+
-
-
{{ctrl.lastQueryMeta.sql}}
-
+
+
{{ctrl.lastQueryMeta.sql}}
+
-
-
Time series:
+  
+
Time series:
 - return column named time or time_sec (in UTC), as a unix time stamp or any sql native date data type. You can use the macros below.
 - return column(s) with numeric datatype as values
 Optional:
@@ -156,7 +162,7 @@ Macros:
 
 Example of group by and order by with $__timeGroup:
 SELECT
-  $__timeGroup(timestamp_col, '1h') AS time,
+  $__timeGroupAlias(timestamp_col, '1h'),
   sum(value_double) as value
 FROM yourtable
 GROUP BY 1
@@ -167,13 +173,13 @@ Or build your own conditionals using these macros which just return the values:
 - $__timeTo() ->  '2017-04-21T05:01:17Z'
 - $__unixEpochFrom() ->  1492750877
 - $__unixEpochTo() ->  1492750877
-		
-
+
+
- + -
-
{{ctrl.lastQueryError}}
-
+
+
{{ctrl.lastQueryError}}
+
From 9bb2b70a95a3d9ec3b49b0bcb12bcde2cb672bab Mon Sep 17 00:00:00 2001 From: Sven Klemm Date: Wed, 24 Oct 2018 19:21:26 +0200 Subject: [PATCH 13/15] only look in current database in findMetricTable --- public/app/plugins/datasource/mysql/meta_query.ts | 1 + 1 file changed, 1 insertion(+) diff --git a/public/app/plugins/datasource/mysql/meta_query.ts b/public/app/plugins/datasource/mysql/meta_query.ts index 9217edb755b..e5f8ad73ebe 100644 --- a/public/app/plugins/datasource/mysql/meta_query.ts +++ b/public/app/plugins/datasource/mysql/meta_query.ts @@ -51,6 +51,7 @@ export class MysqlMetaQuery { ) AS value_column FROM information_schema.tables t WHERE + t.table_schema = database() AND EXISTS ( SELECT 1 FROM information_schema.columns c From 00a997b7a83ca43db87e2a997b6728ef84b95f49 Mon Sep 17 00:00:00 2001 From: Marcus Efraimsson Date: Tue, 30 Oct 2018 15:45:39 +0100 Subject: [PATCH 14/15] docs: mysql --- docs/sources/features/datasources/mysql.md | 52 ++++++++++++++++++++++ 1 file changed, 52 insertions(+) diff --git a/docs/sources/features/datasources/mysql.md b/docs/sources/features/datasources/mysql.md index 988f632bff3..0623f12d200 100644 --- a/docs/sources/features/datasources/mysql.md +++ b/docs/sources/features/datasources/mysql.md @@ -73,6 +73,58 @@ Example: You can use wildcards (`*`) in place of database or table if you want to grant access to more databases and tables. +## Query Editor + +> Only available in Grafana v5.4+. + +{{< docs-imagebox img="/img/docs/v54/mysql_query_still.png" class="docs-image--no-shadow" animated-gif="/img/docs/v54/mysql_query.gif" >}} + +You find the MySQL query editor in the metrics tab in a panel's edit mode. You enter edit mode by clicking the +panel title, then edit. + +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. + +### Select table, time column and metric column (FROM) + +When you enter edit mode for the first time or add a new query Grafana will try to prefill the query builder with the first table that has a timestamp column and a numeric column. + +In the FROM field, Grafana will suggest tables that are in the configured database. You can also manually enter a fully qualified name (schema.table) like `public.metrics`. + +The Time column field refers to the name of the column holding your time values. Selecting a value for the Metric column field is optional. If a value is selected, the Metric column field will be used as the series name. + +The metric column suggestions will only contain columns with a text datatype (text, tinytext, mediumtext, longtext, varchar, char). +If you want to use a column with a different datatype as metric column you may enter the column name with a cast: `CAST(numericColumn as CHAR)`. +You may also enter arbitrary SQL expressions in the metric column field that evaluate to a text datatype like +`CONCAT(column1, " ", CAST(numericColumn as CHAR))`. + +### Columns and Aggregation functions (SELECT) + +In the `SELECT` row you can specify what columns and functions you want to use. +In the column field you may write arbitrary expressions instead of a column name like `column1 * column2 / column3`. + +If you use aggregate functions you need to group your resultset. The editor will automatically add a `GROUP BY time` if you add an aggregate function. + +You may add further value columns by clicking the plus button and selecting `Column` from the menu. Multiple value columns will be plotted as separate series in the graph panel. + +### Filter data (WHERE) +To add a filter click the plus icon to the right of the `WHERE` condition. You can remove filters by clicking on +the filter and selecting `Remove`. A filter for the current selected timerange is automatically added to new queries. + +### Group By +To group by time or any other columns click the plus icon at the end of the GROUP BY row. The suggestion dropdown will only show text columns of your currently selected table but you may manually enter any column. +You can remove the group by clicking on the item and then selecting `Remove`. + +If you add any grouping, all selected columns need to have an aggregate function applied. The query builder will automatically add aggregate functions to all columns without aggregate functions when you add groupings. + +#### Gap Filling + +Grafana can fill in missing values when you group by time. The time function accepts two arguments. The first argument is the time window that you would like to group by, and the second argument is the value you want Grafana to fill missing items with. + +### Text Editor Mode (RAW) +You can switch to the raw query editor mode by clicking the hamburger icon and selecting `Switch editor mode` or by clicking `Edit SQL` below the query. + +> If you use the raw query editor, be sure your query at minimum has `ORDER BY time` and a filter on the returned time range. + ## Macros To simplify syntax and to allow for dynamic parts, like date range filters, the query can contain macros. From a00999fd8944a16b070c21395bf2302db4c22aba Mon Sep 17 00:00:00 2001 From: Marcus Efraimsson Date: Tue, 30 Oct 2018 16:25:36 +0100 Subject: [PATCH 15/15] docs: schema -> database --- docs/sources/features/datasources/mysql.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/docs/sources/features/datasources/mysql.md b/docs/sources/features/datasources/mysql.md index 0623f12d200..bc4e4df6cf9 100644 --- a/docs/sources/features/datasources/mysql.md +++ b/docs/sources/features/datasources/mysql.md @@ -88,7 +88,7 @@ The query editor has a link named `Generated SQL` that shows up after a query ha When you enter edit mode for the first time or add a new query Grafana will try to prefill the query builder with the first table that has a timestamp column and a numeric column. -In the FROM field, Grafana will suggest tables that are in the configured database. You can also manually enter a fully qualified name (schema.table) like `public.metrics`. +In the FROM field, Grafana will suggest tables that are in the configured database. To select a table or view in another database that your database user has access to you can manually enter a fully qualified name (database.table) like `otherDb.metrics`. The Time column field refers to the name of the column holding your time values. Selecting a value for the Metric column field is optional. If a value is selected, the Metric column field will be used as the series name.