diff --git a/README.md b/README.md index f8d39cd..19b6c9d 100644 --- a/README.md +++ b/README.md @@ -125,6 +125,21 @@ trigger.after(:insert).declare("user_type text; status text") do end ``` +#### new_as(name) or old_as(name) +PostgreSQL-specific option for accessing in the after trigger the table as it was before the operation (old) or as it is after the operation (new). This is useful in statement trigger when you want to compare the old and new values of all rows changed during an update trigger. For example: + +```ruby +trigger.after(:update).for_each(:statement).new_as(:new_users).old_as(:old_users) do + <<-SQL + INSERT INTO user_changes(id, old_name, new_name) FROM ( + SELECT new_users.id, old_users.name AS old_name, new_users.name AS new_name + FROM new_users + INNER JOIN old_users ON new_users.id = old_users.id + ) agg + SQL +end +``` + #### all Noop, useful for trigger groups (see below). diff --git a/lib/hair_trigger/builder.rb b/lib/hair_trigger/builder.rb index 818750f..1880413 100644 --- a/lib/hair_trigger/builder.rb +++ b/lib/hair_trigger/builder.rb @@ -82,6 +82,18 @@ def of(*columns) options[:of] = columns end + def old_as(table) + raise DeclarationError, "`old_as' requested, but no table_name specified" unless table.present? + options[:referencing] ||= {} + options[:referencing][:old] = table + end + + def new_as(table) + raise DeclarationError, "`new_as' requested, but no table_name specified" unless table.present? + options[:referencing] ||= {} + options[:referencing][:new] = table + end + def declare(declarations) options[:declarations] = declarations end @@ -159,7 +171,7 @@ def set_#{method}(*args, &block) METHOD end end - chainable_methods :name, :on, :for_each, :before, :after, :where, :security, :timing, :events, :all, :nowrap, :of, :declare + chainable_methods :name, :on, :for_each, :before, :after, :where, :security, :timing, :events, :all, :nowrap, :of, :declare, :old_as, :new_as def create_grouped_trigger? adapter_name == :mysql || adapter_name == :trilogy || adapter_name == :mysql2rgeo @@ -306,6 +318,10 @@ def chained_calls_to_ruby(join_str = '.') "where(#{prepared_where.inspect})" when :of "of(#{options[:of].inspect[1..-2]})" + when :old_as + "old_as(#{options[:referencing][:old].inspect})" + when :new_as + "new_as(#{options[:referencing][:new].inspect})" when :for_each "for_each(#{options[:for_each].downcase.to_sym.inspect})" when :declare @@ -405,6 +421,23 @@ def supports_of? end end + def referencing_clause(check_support = true) + if options[:referencing] && (!check_support || supports_referencing?) + "REFERENCING " + options[:referencing].map{ |k, v| "#{k.to_s.upcase} TABLE AS #{v}" }.join(" ") + end + end + + def supports_referencing? + case adapter_name + when :sqlite, :mysql + false + when :postgresql, :postgis + db_version >= 100000 + else + false + end + end + def generate_drop_trigger case adapter_name when :sqlite, :mysql, :trilogy, :mysql2rgeo @@ -433,6 +466,7 @@ def generate_trigger_postgresql raise GenerationError, "security cannot be used in conjunction with nowrap" if options[:nowrap] && options[:security] raise GenerationError, "where can only be used in conjunction with nowrap on postgres 9.0 and greater" if options[:nowrap] && prepared_where && db_version < 90000 raise GenerationError, "of can only be used in conjunction with nowrap on postgres 9.1 and greater" if options[:nowrap] && options[:of] && db_version < 90100 + raise GenerationError, "referencing can only be used on postgres 10.0 and greater" if options[:referencing] && db_version < 100000 sql = '' @@ -472,6 +506,7 @@ def generate_trigger_postgresql [sql, <<-SQL] CREATE TRIGGER #{prepared_name} #{options[:timing]} #{options[:events].join(" OR ")} #{of_clause}ON #{adapter.quote_table_name(options[:table])} +#{referencing_clause} FOR EACH #{options[:for_each]}#{prepared_where && db_version >= 90000 ? " WHEN (" + prepared_where + ')': ''} EXECUTE PROCEDURE #{trigger_action}; SQL end diff --git a/spec/builder_spec.rb b/spec/builder_spec.rb index 912d9a3..6bd501c 100644 --- a/spec/builder_spec.rb +++ b/spec/builder_spec.rb @@ -253,6 +253,12 @@ def builder(name = nil) expect(trigger.generate.grep(/AFTER UPDATE OF bar, baz/).size).to eql(1) end + it "should reject use of referencing pre-10.0" do + expect { + builder.on(:foos).after(:update).new_as("new_table").old_as("old_table"){ "FOO" }.generate + }.to raise_error /referencing can only be used on postgres 10.0 and greater/ + end + it "should accept security" do expect(builder.on(:foos).after(:update).security(:invoker){ "FOO" }.generate. grep(/SECURITY/).size).to eql(0) # default, so we don't include it @@ -310,6 +316,17 @@ def builder(name = nil) to match(/DECLARE\s*foo INT;\s*BEGIN\s*FOO/) end + context ">= 10.0" do + before(:each) do + @adapter = MockAdapter.new("postgresql", :postgresql_version => 100000) + end + + it "should accept `new_as' and `old_as' tables" do + trigger = builder.on(:foos).after(:update).new_as("new_table").old_as("old_table"){ "FOO" } + expect(trigger.generate.grep(/REFERENCING NEW TABLE AS new_table OLD TABLE AS old_table/).size).to eql(1) + end + end + context "legacy" do it "should reject truncate pre-8.4" do @adapter = MockAdapter.new("postgresql", :postgresql_version => 80300)