meta_query.ts 5.2 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176
  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. table_schema IN (
  49. SELECT CASE WHEN trim(unnest) = '"$user"' THEN user ELSE trim(unnest) END
  50. FROM unnest(string_to_array(current_setting('search_path'),','))
  51. ) AND
  52. EXISTS
  53. ( SELECT 1
  54. FROM information_schema.columns c
  55. WHERE
  56. c.table_schema = t.table_schema AND
  57. c.table_name = t.table_name AND
  58. udt_name IN ('timestamptz','timestamp')
  59. ) AND
  60. EXISTS
  61. ( SELECT 1
  62. FROM information_schema.columns c
  63. WHERE
  64. c.table_schema = t.table_schema AND
  65. c.table_name = t.table_name AND
  66. udt_name='float8'
  67. )
  68. LIMIT 1
  69. ;`;
  70. return query;
  71. }
  72. buildSchemaConstraint() {
  73. let query = `
  74. table_schema IN (
  75. SELECT CASE WHEN trim(unnest) = \'"$user"\' THEN user ELSE trim(unnest) END
  76. FROM unnest(string_to_array(current_setting(\'search_path\'),\',\'))
  77. )`;
  78. return query;
  79. }
  80. buildTableConstraint(table: string) {
  81. let query = '';
  82. // check for schema qualified table
  83. if (table.includes('.')) {
  84. let parts = table.split('.');
  85. query = 'table_schema = ' + this.quoteIdentAsLiteral(parts[0]);
  86. query += ' AND table_name = ' + this.quoteIdentAsLiteral(parts[1]);
  87. return query;
  88. } else {
  89. query = `
  90. table_schema IN (
  91. SELECT CASE WHEN trim(unnest) = \'"$user"\' THEN user ELSE trim(unnest) END
  92. FROM unnest(string_to_array(current_setting(\'search_path\'),\',\'))
  93. )`;
  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','char','varchar')";
  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','char','varchar')";
  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 += ' ORDER BY 1 LIMIT 100';
  135. return query;
  136. }
  137. buildDatatypeQuery(column: string) {
  138. let query = `
  139. SELECT udt_name
  140. FROM information_schema.columns
  141. WHERE
  142. table_schema IN (
  143. SELECT schema FROM (
  144. SELECT CASE WHEN trim(unnest) = \'"$user"\' THEN user ELSE trim(unnest) END as schema
  145. FROM unnest(string_to_array(current_setting(\'search_path\'),\',\'))
  146. ) s
  147. WHERE EXISTS (SELECT 1 FROM information_schema.schemata WHERE schema_name = s.schema)
  148. )
  149. `;
  150. query += ' AND table_name = ' + this.quoteIdentAsLiteral(this.target.table);
  151. query += ' AND column_name = ' + this.quoteIdentAsLiteral(column);
  152. return query;
  153. }
  154. buildAggregateQuery() {
  155. let query = 'SELECT DISTINCT proname FROM pg_aggregate ';
  156. query += 'INNER JOIN pg_proc ON pg_aggregate.aggfnoid = pg_proc.oid ';
  157. query += 'INNER JOIN pg_type ON pg_type.oid=pg_proc.prorettype ';
  158. query += "WHERE pronargs=1 AND typname IN ('float8') AND aggkind='n' ORDER BY 1";
  159. return query;
  160. }
  161. }