meta_query.ts 4.8 KB

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