Skip to content

Commit

Permalink
Fix recreating indexes for materialized views within custom schemas
Browse files Browse the repository at this point in the history
  • Loading branch information
fatkodima committed Jul 2, 2022
1 parent c997e90 commit 549e9a3
Show file tree
Hide file tree
Showing 2 changed files with 74 additions and 17 deletions.
14 changes: 12 additions & 2 deletions lib/scenic/adapters/postgres/indexes.rb
Original file line number Diff line number Diff line change
Expand Up @@ -23,6 +23,7 @@ def on(name)
delegate :quote_table_name, to: :connection

def indexes_on(name)
schema, table = extract_schema_and_table(name.to_s)
connection.execute(<<-SQL)
SELECT
t.relname as object_name,
Expand All @@ -34,8 +35,8 @@ def indexes_on(name)
LEFT JOIN pg_namespace n ON n.oid = i.relnamespace
WHERE i.relkind = 'i'
AND d.indisprimary = 'f'
AND t.relname = '#{name}'
AND n.nspname = ANY (current_schemas(false))
AND t.relname = #{connection.quote(table)}
AND n.nspname = #{schema ? connection.quote(schema) : 'ANY (current_schemas(false))'}
ORDER BY i.relname
SQL
end
Expand All @@ -47,6 +48,15 @@ def index_from_database(result)
definition: result["definition"],
)
end

def extract_schema_and_table(string)
schema, table = string.scan(/[^".]+|"[^"]*"/)
if table.nil?
table = schema
schema = nil
end
[schema, table]
end
end
end
end
Expand Down
77 changes: 62 additions & 15 deletions spec/scenic/adapters/postgres_spec.rb
Original file line number Diff line number Diff line change
Expand Up @@ -52,6 +52,46 @@ module Adapters
end
end

describe "#update_materialized_view" do
it "handles views with custom schemas" do
adapter = Postgres.new
connection = ActiveRecord::Base.connection
previous_search_path = connection.select_value("SHOW search_path")

begin
connection.execute <<-SQL
CREATE SCHEMA scenic;
SET search_path TO scenic, public;
SQL

adapter.create_materialized_view(
"scenic.greetings",
"SELECT text 'hi' AS greeting",
)
connection.add_index("scenic.greetings", :greeting,
name: "index_greetings_on_greeting", unique: true)

silence_stream(STDOUT) do
adapter.update_materialized_view(
"scenic.greetings",
"SELECT text 'hello' AS greeting",
)
end

view = adapter.views.first
expect(view.name).to eq("scenic.greetings")
expect(view.materialized).to eq true

index = connection.indexes("scenic.greetings").first
expect(index.columns).to eq(["greeting"])
expect(index.unique).to eq true
ensure
connection.drop_schema("scenic")
connection.execute("SET search_path TO #{previous_search_path}")
end
end
end

describe "#replace_view" do
it "successfully replaces a view" do
adapter = Postgres.new
Expand Down Expand Up @@ -186,21 +226,28 @@ module Adapters
context "with views in non public schemas" do
it "returns also the non public views" do
adapter = Postgres.new

ActiveRecord::Base.connection.execute <<-SQL
CREATE VIEW parents AS SELECT text 'Joe' AS name
SQL

ActiveRecord::Base.connection.execute <<-SQL
CREATE SCHEMA scenic;
CREATE VIEW scenic.parents AS SELECT text 'Maarten' AS name;
SET search_path TO scenic, public;
SQL

expect(adapter.views.map(&:name)).to eq [
"parents",
"scenic.parents",
]
connection = ActiveRecord::Base.connection
previous_search_path = connection.select_value("SHOW search_path")

begin
connection.execute <<-SQL
CREATE VIEW parents AS SELECT text 'Joe' AS name
SQL

connection.execute <<-SQL
CREATE SCHEMA scenic;
CREATE VIEW scenic.parents AS SELECT text 'Maarten' AS name;
SET search_path TO scenic, public;
SQL

expect(adapter.views.map(&:name)).to eq [
"parents",
"scenic.parents",
]
ensure
connection.drop_schema("scenic")
connection.execute("SET search_path TO #{previous_search_path}")
end
end
end
end
Expand Down

0 comments on commit 549e9a3

Please sign in to comment.