meta_query.ts 4.0 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141
  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. )
  44. ( SELECT 1
  45. FROM information_schema.columns c
  46. WHERE
  47. c.table_schema = t.table_schema AND
  48. c.table_name = t.table_name AND
  49. udt_name='float8'
  50. )
  51. LIMIT 1
  52. ;`;
  53. return query;
  54. }
  55. buildTableQuery() {
  56. let query = `
  57. SELECT quote_ident(table_name)
  58. FROM information_schema.tables
  59. WHERE
  60. table_schema IN (
  61. SELECT CASE WHEN trim(unnest) = \'"$user"\' THEN user ELSE trim(unnest) END
  62. FROM unnest(string_to_array(current_setting(\'search_path\'),\',\'))
  63. )
  64. ORDER BY table_name`;
  65. return query;
  66. }
  67. buildColumnQuery(type?: string) {
  68. let query = `
  69. SELECT quote_ident(column_name)
  70. FROM information_schema.columns
  71. WHERE
  72. table_schema IN (
  73. SELECT CASE WHEN trim(unnest) = \'"$user"\' THEN user ELSE trim(unnest) END
  74. FROM unnest(string_to_array(current_setting(\'search_path\'),\',\'))
  75. LIMIT 1
  76. )
  77. `;
  78. query += ' AND table_name = ' + this.quoteIdentAsLiteral(this.target.table);
  79. switch (type) {
  80. case 'time': {
  81. query +=
  82. " AND data_type IN ('timestamp without time zone','timestamp with time zone','bigint','integer','double precision','real')";
  83. break;
  84. }
  85. case 'metric': {
  86. query += " AND data_type IN ('text','char','varchar')";
  87. break;
  88. }
  89. case 'value': {
  90. query += " AND data_type IN ('bigint','integer','double precision','real')";
  91. query += ' AND column_name <> ' + this.quoteIdentAsLiteral(this.target.timeColumn);
  92. break;
  93. }
  94. case 'groupby': {
  95. query += " AND data_type IN ('text','char','varchar')";
  96. break;
  97. }
  98. }
  99. query += ' ORDER BY column_name';
  100. return query;
  101. }
  102. buildValueQuery(column: string) {
  103. let query = 'SELECT DISTINCT quote_literal(' + column + ')';
  104. query += ' FROM ' + this.target.table;
  105. query += ' WHERE $__timeFilter(' + this.target.timeColumn + ')';
  106. query += ' ORDER BY 1 LIMIT 100';
  107. return query;
  108. }
  109. buildDatatypeQuery(column: string) {
  110. let query = `
  111. SELECT data_type
  112. FROM information_schema.columns
  113. WHERE
  114. table_schema IN (
  115. SELECT CASE WHEN trim(unnest) = \'"$user"\' THEN user ELSE trim(unnest) END
  116. FROM unnest(string_to_array(current_setting(\'search_path\'),\',\'))
  117. LIMIT 1
  118. )
  119. `;
  120. query += ' AND table_name = ' + this.quoteIdentAsLiteral(this.target.table);
  121. query += ' AND column_name = ' + this.quoteIdentAsLiteral(column);
  122. return query;
  123. }
  124. buildAggregateQuery() {
  125. let query = 'SELECT DISTINCT proname FROM pg_aggregate ';
  126. query += 'INNER JOIN pg_proc ON pg_aggregate.aggfnoid = pg_proc.oid ';
  127. query += 'INNER JOIN pg_type ON pg_type.oid=pg_proc.prorettype ';
  128. query += "WHERE pronargs=1 AND typname IN ('float8') AND aggkind='n' ORDER BY 1";
  129. return query;
  130. }
  131. }