Skip to content

Support arbitrary expressions in sum_cache and sum_through_many_cache #10

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Closed
wants to merge 9 commits into from
14 changes: 12 additions & 2 deletions README.rdoc
Original file line number Diff line number Diff line change
Expand Up @@ -100,6 +100,10 @@ or deleted from, records in the main table are updated with the
count of the corresponding records in the counted table. The counter
cache column must have a default of 0 for this to work correctly.

Use pgt_sum_cache with a Sequel expression in summed_column to
handle any custom logic such as a counter cache that only counts
certain rows.

Arguments:
main_table :: name of table holding counter cache column
main_table_id_column :: column in main table matching counted_table_id_column in counted_table
Expand All @@ -115,20 +119,26 @@ of records in the main table, it stores the sum on one of the
columns in summed table. The sum cache column must have a default
of 0 for this to work correctly.

Use a Sequel expression in summed_column to handle any custom
logic such as a counter cache that only counts certain rows, or a
sum cache that sums the length of a string column.

Arguments:
main_table :: name of table holding counter cache column
main_table_id_column :: column in main table matching counted_table_id_column in counted_table
sum_column :: column in main table containing the sum cache
summed_table :: name of table being summed
summed_table_id_column :: column in summed_table matching main_table_id_column in main_table
summed_column :: column in summed_table being summed
summed_column :: column in summed_table being summed or a Sequel expression to be evaluated in the context of summed_table
opts :: options hash

=== Sum Through Many Cache - pgt_sum_through_many_cache

Similar to pgt_sum_cache, except instead of a one-to-many relationship,
it supports a many-to-many relationship with a single join table. The
sum cache column must have a default of 0 for this to work correctly.
Use a Sequel expression in summed_column to handle any custom logic.
See pgt_sum_cache for details.

This takes a single options hash argument, supporting the following options
in addition to the standard options:
Expand All @@ -137,7 +147,7 @@ in addition to the standard options:
:sum_column :: column in main table containing the sum cache, must be NOT NULL and default to 0
:summed_table :: name of table being summed
:summed_table_id_column :: primary key column in summed_table referenced by summed_table_fk_column (default: :id)
:summed_column :: column in summed_table being summed, must be NOT NULL
:summed_column :: column in summed_table being summed or a Sequel expression to be evaluated in the context of summed_table, must be NOT NULL
:join_table :: name of table which joins main_table with summed_table
:join_trigger_name :: name of trigger for join table
:join_function_name :: name of trigger function for join table
Expand Down
35 changes: 21 additions & 14 deletions lib/sequel/extensions/pg_triggers.rb
Original file line number Diff line number Diff line change
Expand Up @@ -73,20 +73,22 @@ def pgt_sum_cache(main_table, main_table_id_column, sum_column, summed_table, su

table = quote_schema_table(main_table)
id_column = quote_identifier(summed_table_id_column)
summed_column = quote_identifier(summed_column)

new_table_summed_column = literal(Sequel.deep_qualify(Sequel.lit("NEW"), summed_column))
old_table_summed_column = literal(Sequel.deep_qualify(Sequel.lit("OLD"), summed_column))
main_column = quote_identifier(main_table_id_column)
sum_column = quote_identifier(sum_column)

pgt_trigger(summed_table, trigger_name, function_name, [:insert, :delete, :update], <<-SQL)
BEGIN
IF (TG_OP = 'UPDATE' AND NEW.#{id_column} = OLD.#{id_column}) THEN
UPDATE #{table} SET #{sum_column} = #{sum_column} + NEW.#{summed_column} - OLD.#{summed_column} WHERE #{main_column} = NEW.#{id_column};
UPDATE #{table} SET #{sum_column} = #{sum_column} + #{new_table_summed_column} - #{old_table_summed_column} WHERE #{main_column} = NEW.#{id_column};
ELSE
IF ((TG_OP = 'INSERT' OR TG_OP = 'UPDATE') AND NEW.#{id_column} IS NOT NULL) THEN
UPDATE #{table} SET #{sum_column} = #{sum_column} + NEW.#{summed_column} WHERE #{main_column} = NEW.#{id_column};
UPDATE #{table} SET #{sum_column} = #{sum_column} + #{new_table_summed_column} WHERE #{main_column} = NEW.#{id_column};
END IF;
IF ((TG_OP = 'DELETE' OR TG_OP = 'UPDATE') AND OLD.#{id_column} IS NOT NULL) THEN
UPDATE #{table} SET #{sum_column} = #{sum_column} - OLD.#{summed_column} WHERE #{main_column} = OLD.#{id_column};
UPDATE #{table} SET #{sum_column} = #{sum_column} - #{old_table_summed_column} WHERE #{main_column} = OLD.#{id_column};
END IF;
END IF;
IF (TG_OP = 'DELETE') THEN
Expand All @@ -108,34 +110,39 @@ def pgt_sum_through_many_cache(opts={})
main_table_fk_column = opts.fetch(:main_table_fk_column)
summed_table_fk_column = opts.fetch(:summed_table_fk_column)

trigger_name = opts[:trigger_name] || "pgt_stmc_#{main_table}__#{main_table_id_column}__#{sum_column}__#{summed_table_id_column}__#{summed_column}__#{main_table_fk_column}__#{summed_table_fk_column}"
function_name = opts[:function_name] || "pgt_stmc_#{main_table}__#{main_table_id_column}__#{sum_column}__#{summed_table}__#{summed_table_id_column}__#{summed_column}__#{join_table}__#{main_table_fk_column}__#{summed_table_fk_column}"
join_trigger_name = opts[:join_trigger_name] || "pgt_stmc_join_#{main_table}__#{main_table_id_column}__#{sum_column}__#{summed_table_id_column}__#{summed_column}__#{main_table_fk_column}__#{summed_table_fk_column}"
join_function_name = opts[:join_function_name] || "pgt_stmc_join_#{main_table}__#{main_table_id_column}__#{sum_column}__#{summed_table}__#{summed_table_id_column}__#{summed_column}__#{join_table}__#{main_table_fk_column}__#{summed_table_fk_column}"
summed_column_slug = summed_column.is_a?(String) || summed_column.is_a?(Symbol) ? "__#{summed_column}" : ""
trigger_name = opts[:trigger_name] || "pgt_stmc_#{main_table}__#{main_table_id_column}__#{sum_column}__#{summed_table_id_column}#{summed_column_slug}__#{main_table_fk_column}__#{summed_table_fk_column}"
function_name = opts[:function_name] || "pgt_stmc_#{main_table}__#{main_table_id_column}__#{sum_column}__#{summed_table}__#{summed_table_id_column}#{summed_column_slug}__#{join_table}__#{main_table_fk_column}__#{summed_table_fk_column}"
join_trigger_name = opts[:join_trigger_name] || "pgt_stmc_join_#{main_table}__#{main_table_id_column}__#{sum_column}__#{summed_table_id_column}#{summed_column_slug}__#{main_table_fk_column}__#{summed_table_fk_column}"
join_function_name = opts[:join_function_name] || "pgt_stmc_join_#{main_table}__#{main_table_id_column}__#{sum_column}__#{summed_table}__#{summed_table_id_column}#{summed_column_slug}__#{join_table}__#{main_table_fk_column}__#{summed_table_fk_column}"

orig_summed_table = summed_table
orig_join_table = join_table

main_table = quote_schema_table(main_table)
main_table_id_column = quote_schema_table(main_table_id_column)
sum_column = quote_schema_table(sum_column)

general_summed_column = literal(Sequel.deep_qualify(summed_table, summed_column))
new_table_summed_column = literal(Sequel.deep_qualify(Sequel.lit("NEW"), summed_column))
old_table_summed_column = literal(Sequel.deep_qualify(Sequel.lit("OLD"), summed_column))

summed_table = quote_schema_table(summed_table)
summed_table_id_column = quote_schema_table(summed_table_id_column)
summed_column = quote_schema_table(summed_column)
join_table = quote_schema_table(join_table)
main_table_fk_column = quote_schema_table(main_table_fk_column)
summed_table_fk_column = quote_schema_table(summed_table_fk_column)

pgt_trigger(orig_summed_table, trigger_name, function_name, [:insert, :delete, :update], <<-SQL)
BEGIN
IF (TG_OP = 'UPDATE' AND NEW.#{summed_table_id_column} = OLD.#{summed_table_id_column}) THEN
UPDATE #{main_table} SET #{sum_column} = #{sum_column} + NEW.#{summed_column} - OLD.#{summed_column} WHERE #{main_table_id_column} IN (SELECT #{main_table_fk_column} FROM #{join_table} WHERE #{summed_table_fk_column} = NEW.#{summed_table_id_column});
UPDATE #{main_table} SET #{sum_column} = #{sum_column} + #{new_table_summed_column} - #{old_table_summed_column} WHERE #{main_table_id_column} IN (SELECT #{main_table_fk_column} FROM #{join_table} WHERE #{summed_table_fk_column} = NEW.#{summed_table_id_column});
ELSE
IF (TG_OP = 'INSERT' OR TG_OP = 'UPDATE') THEN
UPDATE #{main_table} SET #{sum_column} = #{sum_column} + NEW.#{summed_column} WHERE #{main_table_id_column} IN (SELECT #{main_table_fk_column} FROM #{join_table} WHERE #{summed_table_fk_column} = NEW.#{summed_table_id_column});
UPDATE #{main_table} SET #{sum_column} = #{sum_column} + #{new_table_summed_column} WHERE #{main_table_id_column} IN (SELECT #{main_table_fk_column} FROM #{join_table} WHERE #{summed_table_fk_column} = NEW.#{summed_table_id_column});
END IF;
IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') THEN
UPDATE #{main_table} SET #{sum_column} = #{sum_column} - OLD.#{summed_column} WHERE #{main_table_id_column} IN (SELECT #{main_table_fk_column} FROM #{join_table} WHERE #{summed_table_fk_column} = OLD.#{summed_table_id_column});
UPDATE #{main_table} SET #{sum_column} = #{sum_column} - #{old_table_summed_column} WHERE #{main_table_id_column} IN (SELECT #{main_table_fk_column} FROM #{join_table} WHERE #{summed_table_fk_column} = OLD.#{summed_table_id_column});
END IF;
END IF;
IF (TG_OP = 'DELETE') THEN
Expand All @@ -149,10 +156,10 @@ def pgt_sum_through_many_cache(opts={})
BEGIN
IF (NOT (TG_OP = 'UPDATE' AND NEW.#{main_table_fk_column} = OLD.#{main_table_fk_column} AND NEW.#{summed_table_fk_column} = OLD.#{summed_table_fk_column})) THEN
IF (TG_OP = 'INSERT' OR TG_OP = 'UPDATE') THEN
UPDATE #{main_table} SET #{sum_column} = #{sum_column} + (SELECT #{summed_column} FROM #{summed_table} WHERE #{summed_table_id_column} = NEW.#{summed_table_fk_column}) WHERE #{main_table_id_column} = NEW.#{main_table_fk_column};
UPDATE #{main_table} SET #{sum_column} = #{sum_column} + (SELECT #{general_summed_column} FROM #{summed_table} WHERE #{summed_table_id_column} = NEW.#{summed_table_fk_column}) WHERE #{main_table_id_column} = NEW.#{main_table_fk_column};
END IF;
IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE') THEN
UPDATE #{main_table} SET #{sum_column} = #{sum_column} - (SELECT #{summed_column} FROM #{summed_table} WHERE #{summed_table_id_column} = OLD.#{summed_table_fk_column}) WHERE #{main_table_id_column} = OLD.#{main_table_fk_column};
UPDATE #{main_table} SET #{sum_column} = #{sum_column} - (SELECT #{general_summed_column} FROM #{summed_table} WHERE #{summed_table_id_column} = OLD.#{summed_table_fk_column}) WHERE #{main_table_id_column} = OLD.#{main_table_fk_column};
END IF;
END IF;
IF (TG_OP = 'DELETE') THEN
Expand Down
149 changes: 149 additions & 0 deletions spec/sequel_postgresql_triggers_spec.rb
Original file line number Diff line number Diff line change
Expand Up @@ -189,6 +189,62 @@
end
end

describe "PostgreSQL Sum Cache Trigger with arbitrary expression" do
before do
DB.create_table(:accounts){integer :id; integer :nonzero_entries_count, :default=>0}
DB.create_table(:entries){integer :id; integer :account_id; integer :amount}
DB.pgt_sum_cache(:accounts, :id, :nonzero_entries_count, :entries, :account_id, Sequel.case({0=>0}, 1, :amount), :function_name=>:spgt_sum_cache)
DB[:accounts] << {:id=>1}
DB[:accounts] << {:id=>2}
end

after do
DB.drop_table(:entries, :accounts)
DB.drop_function(:spgt_sum_cache)
end

it "Should modify sum cache when adding, updating, or removing records" do
DB[:accounts].order(:id).select_map(:nonzero_entries_count).must_equal [0, 0]

DB[:entries] << {:id=>1, :account_id=>1, :amount=>100}
DB[:accounts].order(:id).select_map(:nonzero_entries_count).must_equal [1, 0]

DB[:entries] << {:id=>2, :account_id=>1, :amount=>200}
DB[:accounts].order(:id).select_map(:nonzero_entries_count).must_equal [2, 0]

DB[:entries] << {:id=>3, :account_id=>nil, :amount=>500}
DB[:accounts].order(:id).select_map(:nonzero_entries_count).must_equal [2, 0]

DB[:entries].where(:id=>3).update(:account_id=>2)
DB[:accounts].order(:id).select_map(:nonzero_entries_count).must_equal [2, 1]

DB[:entries].exclude(:id=>2).update(:amount=>Sequel.*(:amount, 2))
DB[:accounts].order(:id).select_map(:nonzero_entries_count).must_equal [2, 1]

DB[:entries].where(:id=>2).update(:account_id=>2)
DB[:accounts].order(:id).select_map(:nonzero_entries_count).must_equal [1, 2]

DB[:entries].where(:id=>2).update(:account_id=>nil)
DB[:accounts].order(:id).select_map(:nonzero_entries_count).must_equal [1, 1]

DB[:entries].where(:id=>2).update(:id=>4)
DB[:accounts].order(:id).select_map(:nonzero_entries_count).must_equal [1, 1]

DB[:entries].where(:id=>4).update(:account_id=>2)
DB[:accounts].order(:id).select_map(:nonzero_entries_count).must_equal [1, 2]

DB[:entries].where(:id=>4).update(:account_id=>nil)
DB[:accounts].order(:id).select_map(:nonzero_entries_count).must_equal [1, 1]

DB[:entries].filter(:id=>4).delete
DB[:accounts].order(:id).select_map(:nonzero_entries_count).must_equal [1, 1]

DB[:entries].delete
DB[:accounts].order(:id).select_map(:nonzero_entries_count).must_equal [0, 0]
end
end


describe "PostgreSQL Sum Through Many Cache Trigger" do
before do
DB.create_table(:parents){primary_key :id; integer :balance, :default=>0, :null=>false}
Expand Down Expand Up @@ -282,6 +338,99 @@
end
end

describe "PostgreSQL Sum Through Many Cache Trigger with arbitrary expression" do
before do
DB.create_table(:parents){primary_key :id; integer :nonzero_entries_count, :default=>0, :null=>false}
DB.create_table(:children){primary_key :id; integer :amount, :null=>false}
DB.create_table(:links){integer :parent_id, :null=>false; integer :child_id, :null=>false; unique [:parent_id, :child_id]}
DB.pgt_sum_through_many_cache(
:main_table=>:parents,
:sum_column=>:nonzero_entries_count,
:summed_table=>:children,
:summed_column=>Sequel.case({0=>0}, 1, :amount),
:join_table=>:links,
:main_table_fk_column=>:parent_id,
:summed_table_fk_column=>:child_id,
:function_name=>:spgt_stm_cache,
:join_function_name=>:spgt_stm_cache_join
)
DB[:parents] << {:id=>1}
DB[:parents] << {:id=>2}
end

after do
DB.drop_table(:links, :parents, :children)
DB.drop_function(:spgt_stm_cache)
DB.drop_function(:spgt_stm_cache_join)
end

it "Should modify sum cache when adding, updating, or removing records" do
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [0, 0]

DB[:children] << {:id=>1, :amount=>100}
DB[:links] << {:parent_id=>1, :child_id=>1}
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [1, 0]

DB[:children] << {:id=>2, :amount=>200}
DB[:links] << {:parent_id=>1, :child_id=>2}
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [2, 0]

DB[:children] << {:id=>3, :amount=>500}
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [2, 0]
DB[:links] << {:parent_id=>2, :child_id=>3}
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [2, 1]

DB[:links].where(:parent_id=>2, :child_id=>3).update(:parent_id=>1)
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [3, 0]

DB[:children] << {:id=>4, :amount=>400}
DB[:links].where(:parent_id=>1, :child_id=>3).update(:child_id=>4)
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [3, 0]

DB[:links].where(:parent_id=>1, :child_id=>4).update(:parent_id=>2, :child_id=>3)
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [2, 1]

DB[:children].exclude(:id=>2).update(:amount=>Sequel.*(:amount, 2))
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [2, 1]

DB[:links].where(:parent_id=>1, :child_id=>2).update(:parent_id=>2)
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [1, 2]

DB[:links].where(:parent_id=>2, :child_id=>2).update(:parent_id=>1)
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [2, 1]

DB[:links].where(:parent_id=>1, :child_id=>2).update(:child_id=>3)
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [2, 1]

DB[:links] << {:parent_id=>2, :child_id=>4}
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [2, 2]

DB[:children].filter(:id=>4).delete
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [2, 1]

DB[:links].filter(:parent_id=>1, :child_id=>1).delete
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [1, 1]

DB[:children] << {:id=>4, :amount=>400}
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [1, 2]

DB[:children].delete
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [0, 0]

DB[:children].multi_insert([{:id=>2, :amount=>200}, {:id=>1, :amount=>200}, {:id=>3, :amount=>1000}, {:id=>4, :amount=>400}])
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [1, 2]

DB[:links].where(:child_id=>3).update(:child_id=>2)
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [1, 2]

DB[:children].update(:amount=>10)
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [1, 2]

DB[:links].delete
DB[:parents].order(:id).select_map(:nonzero_entries_count).must_equal [0, 0]
end
end

describe "PostgreSQL Updated At Trigger" do
before do
DB.create_table(:accounts){integer :id; timestamp :changed_on}
Expand Down