meta_query.ts 5.0 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169
  1. import QueryModel from './postgres_query_model';
  2. export class PostgresMetaQuery {
  3. constructor(private target: { table: string; timeColumn: string }, private queryModel: QueryModel) {}
  4. getOperators(datatype: string) {
  5. switch (datatype) {
  6. case 'float4':
  7. case 'float8': {
  8. return ['=', '!=', '<', '<=', '>', '>='];
  9. }
  10. case 'text':
  11. case 'varchar':
  12. case 'char': {
  13. return ['=', '!=', '<', '<=', '>', '>=', 'IN', 'NOT IN', 'LIKE', 'NOT LIKE', '~', '~*', '!~', '!~*'];
  14. }
  15. default: {
  16. return ['=', '!=', '<', '<=', '>', '>=', 'IN', 'NOT IN'];
  17. }
  18. }
  19. }
  20. // quote identifier as literal to use in metadata queries
  21. quoteIdentAsLiteral(value: string) {
  22. return this.queryModel.quoteLiteral(this.queryModel.unquoteIdentifier(value));
  23. }
  24. findMetricTable() {
  25. // query that returns first table found that has a timestamp(tz) column and a float column
  26. let query = `
  27. SELECT
  28. quote_ident(table_name) as table_name,
  29. ( SELECT
  30. quote_ident(column_name) as column_name
  31. FROM information_schema.columns c
  32. WHERE
  33. c.table_schema = t.table_schema AND
  34. c.table_name = t.table_name AND
  35. udt_name IN ('timestamptz','timestamp')
  36. ORDER BY ordinal_position LIMIT 1
  37. ) AS time_column,
  38. ( SELECT
  39. quote_ident(column_name) AS column_name
  40. FROM information_schema.columns c
  41. WHERE
  42. c.table_schema = t.table_schema AND
  43. c.table_name = t.table_name AND
  44. udt_name='float8'
  45. ORDER BY ordinal_position LIMIT 1
  46. ) AS value_column
  47. FROM information_schema.tables t
  48. WHERE `;
  49. query += this.buildSchemaConstraint();
  50. query += ` AND
  51. EXISTS
  52. ( SELECT 1
  53. FROM information_schema.columns c
  54. WHERE
  55. c.table_schema = t.table_schema AND
  56. c.table_name = t.table_name AND
  57. udt_name IN ('timestamptz','timestamp')
  58. ) AND
  59. EXISTS
  60. ( SELECT 1
  61. FROM information_schema.columns c
  62. WHERE
  63. c.table_schema = t.table_schema AND
  64. c.table_name = t.table_name AND
  65. udt_name='float8'
  66. )
  67. LIMIT 1
  68. ;`;
  69. return query;
  70. }
  71. buildSchemaConstraint() {
  72. // quote_ident protects hyphenated schemes
  73. const query = `
  74. quote_ident(table_schema) IN (
  75. SELECT
  76. CASE WHEN trim(s[i]) = '"$user"' THEN user ELSE trim(s[i]) END
  77. FROM
  78. generate_series(
  79. array_lower(string_to_array(current_setting('search_path'),','),1),
  80. array_upper(string_to_array(current_setting('search_path'),','),1)
  81. ) as i,
  82. string_to_array(current_setting('search_path'),',') s
  83. )`;
  84. return query;
  85. }
  86. buildTableConstraint(table: string) {
  87. let query = '';
  88. // check for schema qualified table
  89. if (table.includes('.')) {
  90. const parts = table.split('.');
  91. query = 'table_schema = ' + this.quoteIdentAsLiteral(parts[0]);
  92. query += ' AND table_name = ' + this.quoteIdentAsLiteral(parts[1]);
  93. return query;
  94. } else {
  95. query = this.buildSchemaConstraint();
  96. query += ' AND table_name = ' + this.quoteIdentAsLiteral(table);
  97. return query;
  98. }
  99. }
  100. buildTableQuery() {
  101. let query = 'SELECT quote_ident(table_name) FROM information_schema.tables WHERE ';
  102. query += this.buildSchemaConstraint();
  103. query += ' ORDER BY table_name';
  104. return query;
  105. }
  106. buildColumnQuery(type?: string) {
  107. let query = 'SELECT quote_ident(column_name) FROM information_schema.columns WHERE ';
  108. query += this.buildTableConstraint(this.target.table);
  109. switch (type) {
  110. case 'time': {
  111. query +=
  112. " AND data_type IN ('timestamp without time zone','timestamp with time zone','bigint','integer','double precision','real')";
  113. break;
  114. }
  115. case 'metric': {
  116. query += " AND data_type IN ('text','character','character varying')";
  117. break;
  118. }
  119. case 'value': {
  120. query += " AND data_type IN ('bigint','integer','double precision','real','numeric')";
  121. query += ' AND column_name <> ' + this.quoteIdentAsLiteral(this.target.timeColumn);
  122. break;
  123. }
  124. case 'group': {
  125. query += " AND data_type IN ('text','character','character varying','uuid')";
  126. break;
  127. }
  128. }
  129. query += ' ORDER BY column_name';
  130. return query;
  131. }
  132. buildValueQuery(column: string) {
  133. let query = 'SELECT DISTINCT quote_literal(' + column + ')';
  134. query += ' FROM ' + this.target.table;
  135. query += ' WHERE $__timeFilter(' + this.target.timeColumn + ')';
  136. query += ' AND ' + column + ' IS NOT NULL';
  137. query += ' ORDER BY 1 LIMIT 100';
  138. return query;
  139. }
  140. buildDatatypeQuery(column: string) {
  141. let query = 'SELECT udt_name FROM information_schema.columns WHERE ';
  142. query += this.buildTableConstraint(this.target.table);
  143. query += ' AND column_name = ' + this.quoteIdentAsLiteral(column);
  144. return query;
  145. }
  146. buildAggregateQuery() {
  147. let query = 'SELECT DISTINCT proname FROM pg_aggregate ';
  148. query += 'INNER JOIN pg_proc ON pg_aggregate.aggfnoid = pg_proc.oid ';
  149. query += 'INNER JOIN pg_type ON pg_type.oid=pg_proc.prorettype ';
  150. query += "WHERE pronargs=1 AND typname IN ('float8') AND aggkind='n' ORDER BY 1";
  151. return query;
  152. }
  153. }