meta_query.ts 4.7 KB

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