123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169 |
- import QueryModel from './postgres_query_model';
- export class PostgresMetaQuery {
- constructor(private target: { table: string; timeColumn: string }, private queryModel: 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: string) {
- 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
- quote_ident(table_name) as table_name,
- ( SELECT
- quote_ident(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
- udt_name IN ('timestamptz','timestamp')
- ORDER BY ordinal_position LIMIT 1
- ) AS time_column,
- ( SELECT
- quote_ident(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
- udt_name='float8'
- ORDER BY ordinal_position LIMIT 1
- ) AS value_column
- FROM information_schema.tables t
- WHERE `;
- query += this.buildSchemaConstraint();
- query += ` AND
- EXISTS
- ( SELECT 1
- FROM information_schema.columns c
- WHERE
- c.table_schema = t.table_schema AND
- c.table_name = t.table_name AND
- udt_name IN ('timestamptz','timestamp')
- ) AND
- EXISTS
- ( SELECT 1
- FROM information_schema.columns c
- WHERE
- c.table_schema = t.table_schema AND
- c.table_name = t.table_name AND
- udt_name='float8'
- )
- LIMIT 1
- ;`;
- return query;
- }
- buildSchemaConstraint() {
- // quote_ident protects hyphenated schemes
- const query = `
- quote_ident(table_schema) IN (
- SELECT
- CASE WHEN trim(s[i]) = '"$user"' THEN user ELSE trim(s[i]) END
- FROM
- generate_series(
- array_lower(string_to_array(current_setting('search_path'),','),1),
- array_upper(string_to_array(current_setting('search_path'),','),1)
- ) as i,
- string_to_array(current_setting('search_path'),',') s
- )`;
- return query;
- }
- buildTableConstraint(table: string) {
- let query = '';
- // check for schema qualified table
- if (table.includes('.')) {
- const parts = table.split('.');
- query = 'table_schema = ' + this.quoteIdentAsLiteral(parts[0]);
- query += ' AND table_name = ' + this.quoteIdentAsLiteral(parts[1]);
- return query;
- } else {
- query = this.buildSchemaConstraint();
- query += ' AND table_name = ' + this.quoteIdentAsLiteral(table);
- return query;
- }
- }
- buildTableQuery() {
- let query = 'SELECT quote_ident(table_name) FROM information_schema.tables WHERE ';
- query += this.buildSchemaConstraint();
- query += ' ORDER BY table_name';
- return query;
- }
- buildColumnQuery(type?: string) {
- let query = 'SELECT quote_ident(column_name) FROM information_schema.columns WHERE ';
- query += this.buildTableConstraint(this.target.table);
- switch (type) {
- case 'time': {
- query +=
- " AND data_type IN ('timestamp without time zone','timestamp with time zone','bigint','integer','double precision','real')";
- break;
- }
- case 'metric': {
- query += " AND data_type IN ('text','character','character varying')";
- break;
- }
- case 'value': {
- query += " AND data_type IN ('bigint','integer','double precision','real','numeric')";
- query += ' AND column_name <> ' + this.quoteIdentAsLiteral(this.target.timeColumn);
- break;
- }
- case 'group': {
- query += " AND data_type IN ('text','character','character varying','uuid')";
- break;
- }
- }
- query += ' ORDER BY column_name';
- return query;
- }
- buildValueQuery(column: string) {
- let query = 'SELECT DISTINCT quote_literal(' + column + ')';
- query += ' FROM ' + this.target.table;
- query += ' WHERE $__timeFilter(' + this.target.timeColumn + ')';
- query += ' AND ' + column + ' IS NOT NULL';
- query += ' ORDER BY 1 LIMIT 100';
- return query;
- }
- buildDatatypeQuery(column: string) {
- let query = 'SELECT udt_name FROM information_schema.columns WHERE ';
- query += this.buildTableConstraint(this.target.table);
- query += ' AND column_name = ' + this.quoteIdentAsLiteral(column);
- return query;
- }
- buildAggregateQuery() {
- let query = 'SELECT DISTINCT proname FROM pg_aggregate ';
- query += 'INNER JOIN pg_proc ON pg_aggregate.aggfnoid = pg_proc.oid ';
- query += 'INNER JOIN pg_type ON pg_type.oid=pg_proc.prorettype ';
- query += "WHERE pronargs=1 AND typname IN ('float8') AND aggkind='n' ORDER BY 1";
- return query;
- }
- }
|