meta_query.ts 3.8 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121
  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_schema,
  12. table_name,
  13. ( SELECT
  14. column_name
  15. FROM information_schema.columns c
  16. WHERE
  17. c.table_schema = t.table_schema AND
  18. c.table_name = t.table_name AND
  19. udt_name IN ('timestamptz','timestamp')
  20. ORDER BY ordinal_position LIMIT 1
  21. ) AS time_column,
  22. ( SELECT
  23. column_name
  24. FROM information_schema.columns c
  25. WHERE
  26. c.table_schema = t.table_schema AND
  27. c.table_name = t.table_name AND
  28. udt_name='float8'
  29. ORDER BY ordinal_position LIMIT 1
  30. ) AS value_column
  31. FROM information_schema.tables t
  32. WHERE
  33. table_schema !~* '^_|^pg_|information_schema' AND
  34. EXISTS
  35. ( SELECT 1
  36. FROM information_schema.columns c
  37. WHERE
  38. c.table_schema = t.table_schema AND
  39. c.table_name = t.table_name AND
  40. udt_name IN ('timestamptz','timestamp')
  41. )
  42. ( SELECT 1
  43. FROM information_schema.columns c
  44. WHERE
  45. c.table_schema = t.table_schema AND
  46. c.table_name = t.table_name AND
  47. udt_name='float8'
  48. )
  49. LIMIT 1
  50. ;`;
  51. return query;
  52. }
  53. buildSchemaQuery() {
  54. let query = 'SELECT quote_ident(schema_name) FROM information_schema.schemata WHERE';
  55. query += " schema_name NOT LIKE 'pg_%' AND schema_name NOT LIKE '\\_%' AND schema_name <> 'information_schema';";
  56. return query;
  57. }
  58. buildTableQuery() {
  59. let query = 'SELECT quote_ident(table_name) FROM information_schema.tables WHERE ';
  60. query += 'table_schema = ' + this.quoteIdentAsLiteral(this.target.schema);
  61. return query;
  62. }
  63. buildColumnQuery(type?: string) {
  64. let query = 'SELECT quote_ident(column_name) FROM information_schema.columns WHERE ';
  65. query += 'table_schema = ' + this.quoteIdentAsLiteral(this.target.schema);
  66. query += ' AND table_name = ' + this.quoteIdentAsLiteral(this.target.table);
  67. switch (type) {
  68. case 'time': {
  69. query +=
  70. " AND data_type IN ('timestamp without time zone','timestamp with time zone','bigint','integer','double precision','real')";
  71. break;
  72. }
  73. case 'metric': {
  74. query += " AND data_type IN ('text','char','varchar')";
  75. break;
  76. }
  77. case 'value': {
  78. query += " AND data_type IN ('bigint','integer','double precision','real')";
  79. query += ' AND column_name <> ' + this.quoteIdentAsLiteral(this.target.timeColumn);
  80. break;
  81. }
  82. case 'groupby': {
  83. query += " AND data_type IN ('text','char','varchar')";
  84. break;
  85. }
  86. }
  87. return query;
  88. }
  89. buildValueQuery(column: string) {
  90. let query = 'SELECT DISTINCT quote_literal(' + column + ')';
  91. query += ' FROM ' + this.target.schema + '.' + this.target.table;
  92. query += ' WHERE $__timeFilter(' + this.target.timeColumn + ')';
  93. query += ' ORDER BY 1 LIMIT 100';
  94. return query;
  95. }
  96. buildDatatypeQuery(column: string) {
  97. let query = 'SELECT data_type FROM information_schema.columns WHERE ';
  98. query += ' table_schema = ' + this.quoteIdentAsLiteral(this.target.schema);
  99. query += ' AND table_name = ' + this.quoteIdentAsLiteral(this.target.table);
  100. query += ' AND column_name = ' + this.quoteIdentAsLiteral(column);
  101. return query;
  102. }
  103. buildAggregateQuery() {
  104. let query = 'SELECT DISTINCT proname FROM pg_aggregate ';
  105. query += 'INNER JOIN pg_proc ON pg_aggregate.aggfnoid = pg_proc.oid ';
  106. query += 'INNER JOIN pg_type ON pg_type.oid=pg_proc.prorettype ';
  107. query += "WHERE pronargs=1 AND typname IN ('float8') AND aggkind='n' ORDER BY 1";
  108. return query;
  109. }
  110. }