From 69a1efd572f6faccd07d5e6eb70d6ec4236534da Mon Sep 17 00:00:00 2001 From: Sandip Trivedi Date: Mon, 6 Apr 2020 16:05:01 -0400 Subject: [PATCH 1/2] Add support for materialized views in the preview table dropdown when creating or editing a query. This addition is only for PostgreSQL. --- lib/blazer/adapters/sql_adapter.rb | 1 + 1 file changed, 1 insertion(+) diff --git a/lib/blazer/adapters/sql_adapter.rb b/lib/blazer/adapters/sql_adapter.rb index c76bbfc0b..c8b06fb95 100644 --- a/lib/blazer/adapters/sql_adapter.rb +++ b/lib/blazer/adapters/sql_adapter.rb @@ -41,6 +41,7 @@ def run_statement(statement, comment) def tables sql = add_schemas("SELECT table_schema, table_name FROM information_schema.tables") + sql = sql + " UNION ALL SELECT schemaname AS table_schema, matviewname AS table_name FROM pg_matviews" if postgresql? result = data_source.run_statement(sql, refresh_cache: true) if postgresql? || redshift? || snowflake? result.rows.sort_by { |r| [r[0] == default_schema ? "" : r[0], r[1]] }.map do |row| From df3e3a4a9a846ad0adddadc78e357b02a6248fd6 Mon Sep 17 00:00:00 2001 From: Sandip Trivedi Date: Fri, 5 Jun 2020 09:17:21 -0400 Subject: [PATCH 2/2] Improve support for materialized views. Take into account both making sure the Blazer user has privileges for the materialized views and the schema settings. This improvement is only for PostgreSQL. --- lib/blazer/adapters/sql_adapter.rb | 53 ++++++++++++++++++++++++++++-- 1 file changed, 50 insertions(+), 3 deletions(-) diff --git a/lib/blazer/adapters/sql_adapter.rb b/lib/blazer/adapters/sql_adapter.rb index c8b06fb95..c2c1436e7 100644 --- a/lib/blazer/adapters/sql_adapter.rb +++ b/lib/blazer/adapters/sql_adapter.rb @@ -40,8 +40,29 @@ def run_statement(statement, comment) end def tables - sql = add_schemas("SELECT table_schema, table_name FROM information_schema.tables") - sql = sql + " UNION ALL SELECT schemaname AS table_schema, matviewname AS table_name FROM pg_matviews" if postgresql? + sql = + if postgresql? + <<-SQL + SELECT table_schema, table_name + FROM ( + SELECT table_schema, table_name FROM information_schema.tables + UNION ALL + SELECT n.nspname AS table_schema, c.relname AS table_name + FROM pg_catalog.pg_class c + LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + WHERE c.relkind = 'm' AND + ( + pg_has_role(c.relowner, 'USAGE') + OR has_table_privilege(c.oid, 'SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER') + OR has_any_column_privilege(c.oid, 'SELECT, INSERT, UPDATE, REFERENCES') + ) + ) AS tables + SQL + else + "SELECT table_schema, table_name FROM information_schema.tables" + end + sql = add_schemas(sql) + result = data_source.run_statement(sql, refresh_cache: true) if postgresql? || redshift? || snowflake? result.rows.sort_by { |r| [r[0] == default_schema ? "" : r[0], r[1]] }.map do |row| @@ -65,7 +86,33 @@ def tables end def schema - sql = add_schemas("SELECT table_schema, table_name, column_name, data_type, ordinal_position FROM information_schema.columns") + sql = + if postgresql? + <<~SQL + SELECT table_schema, table_name, column_name, data_type, ordinal_position + FROM ( + SELECT table_schema, table_name, column_name, data_type, ordinal_position + FROM information_schema.columns + UNION ALL + SELECT + n.nspname AS table_schema, c.relname AS table_name, a.attname AS column_name, TRIM(leading '_' FROM t.typname) AS data_type, a.attnum AS ordinal_position + FROM pg_catalog.pg_class c + LEFT JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid + INNER JOIN pg_catalog.pg_attribute a ON c.oid = a.attrelid + JOIN pg_catalog.pg_type t ON t.typelem = a.atttypid + WHERE c.relkind = 'm' AND a.attnum >= 1 AND + ( + pg_has_role(c.relowner, 'USAGE') + OR has_table_privilege(c.oid, 'SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER') + OR has_any_column_privilege(c.oid, 'SELECT, INSERT, UPDATE, REFERENCES') + ) + ) AS schemas + SQL + else + "SELECT table_schema, table_name, column_name, data_type, ordinal_position FROM information_schema.columns" + end + + sql = add_schemas(sql) result = data_source.run_statement(sql) result.rows.group_by { |r| [r[0], r[1]] }.map { |k, vs| {schema: k[0], table: k[1], columns: vs.sort_by { |v| v[2] }.map { |v| {name: v[2], data_type: v[3]} }} }.sort_by { |t| [t[:schema] == default_schema ? "" : t[:schema], t[:table]] } end