Skip to content

Commit

Permalink
Initial commit
Browse files Browse the repository at this point in the history
  • Loading branch information
jeremyevans committed Dec 12, 2008
0 parents commit ff582a0
Show file tree
Hide file tree
Showing 7 changed files with 415 additions and 0 deletions.
2 changes: 2 additions & 0 deletions .gitignore
Original file line number Diff line number Diff line change
@@ -0,0 +1,2 @@
rdoc
*.gem
18 changes: 18 additions & 0 deletions LICENSE
Original file line number Diff line number Diff line change
@@ -0,0 +1,18 @@
Copyright (c) 2008 Jeremy Evans

Permission is hereby granted, free of charge, to any person obtaining a copy
of this software and associated documentation files (the "Software"), to
deal in the Software without restriction, including without limitation the
rights to use, copy, modify, merge, publish, distribute, sublicense, and/or
sell copies of the Software, and to permit persons to whom the Software is
furnished to do so, subject to the following conditions:

The above copyright notice and this permission notice shall be included in
all copies or substantial portions of the Software.

THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL
THE AUTHORS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER
IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN
CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE.
60 changes: 60 additions & 0 deletions README
Original file line number Diff line number Diff line change
@@ -0,0 +1,60 @@
= Sequel PostgreSQL Triggers

Sequel PostgreSQL Triggers is a small enhancement to Sequel allowing
a user to easily handle the following types of columns:

* Timestamp Columns (Created Ad/Updated At)
* Counter/Sum Caches
* Immutable Columns

It handles these internally to the database via triggers, so even if
other applications access the database (without using Sequel), things
will still work (unless the database superuser disables triggers).

To use any of these methods, you have to add the plpgsql procedural
language to PostgreSQL, which you can do with:

DB.create_language(:plpgsql)

== Triggers

=== Created At Columns - pgt_created_at

pgt_created_at takes the table and column given and makes it so that
upon insertion, the column is set to the CURRENT_TIMESTAMP, and that
upon update, the column's value is always set to the previous value.
This is sort of like an immutable column, but it doesn't bring up an
error if you try to change it, it just ignores it.

=== Updated At Columns - pgt_updated_at

Similar to pgt_created_at, takes a table and column and makes it so
that upon insertion, the column is set to CURRENT_TIMESTAMP. It
differs that upon up, the column is also set to CURRENT_TIMESTAMP.

=== Counter Cache - pgt_counter_cache

This takes quite a few arguments (see the RDoc) and sets up a
counter cache so that when the counted table is inserted to
or deleted from, records in the main table are updated with the
count of the corresponding records in the counted table.

=== Sum Cache - pgt_sum_cache

Similar to pgt_counter_cache, except instead of storing a count
of records in the main table, it stores the sum on one of the
columns in summed table.

=== Immutable Columns - pgt_immutable

This takes a table name and one or more column names, and adds
an update trigger that raises an exception if you try to modify
the value of any of the columns.

== License

This library is released under the MIT License. See the LICENSE file for details.

== Author

Jeremy Evans <code@jeremyevans.net>
29 changes: 29 additions & 0 deletions Rakefile
Original file line number Diff line number Diff line change
@@ -0,0 +1,29 @@
require "rake"
require "rake/clean"
require "spec/rake/spectask"
begin
require "hanna/rdoctask"
rescue LoadError
require "rake/rdoctask"
end

CLEAN.include ["*.gem", "rdoc"]
RDOC_OPTS = ["--quiet", "--line-numbers", "--inline-source", '--title', \
'Sequel PostgreSQL Triggers: Database enforced timestamps, immutable columns, and counter/sum caches', '--main', 'README']

Rake::RDocTask.new do |rdoc|
rdoc.rdoc_dir = "rdoc"
rdoc.options += RDOC_OPTS
rdoc.rdoc_files.add %w"README LICENSE lib/sequel_postgresql_triggers.rb"
end

desc "Run specs"
Spec::Rake::SpecTask.new("spec") do |t|
t.spec_files = ["spec/sequel_postgresql_triggers_spec.rb"]
end
task :default=>[:spec]

desc "Package sequel_postgresql_triggers"
task :package do
sh %{gem build sequel_postgresql_triggers.gemspec}
end
140 changes: 140 additions & 0 deletions lib/sequel_postgresql_triggers.rb
Original file line number Diff line number Diff line change
@@ -0,0 +1,140 @@
module Sequel
module Postgres
# Add the pgt_* methods so that any Sequel database connecting to PostgreSQL
# can use them. All of these methods require the plpgsql procedural language
# added to the PostgreSQL database before they can be used. You can do so
# with:
#
# DB.create_language(:plpgsql)
#
# All of the public methods take the following options in their opts hash:
#
# * :function_name: The name of the function to use. This is important
# to specify if you want an easy way to drop the function.
# * :trigger_name: The name of the trigger to use. This is important
# to specify if you want an easy way to drop the trigger.
module DatabaseMethods
# Turns a column in the main table into a counter cache. A counter cache is a
# column in the main table with the number of rows in the counted table
# for the matching id. 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
# * counter_column : column in main table containing the counter cache
# * counted_table : name of table being counted
# * counted_table_id_column : column in counted_table matching main_table_id_column in main_table
# * opts : option hash, see module documentation
def pgt_counter_cache(main_table, main_table_id_column, counter_column, counted_table, counted_table_id_column, opts={})
trigger_name = opts[:trigger_name] || "pgt_cc_#{main_table}__#{main_table_id_column}__#{counter_column}__#{counted_table_id_column}"
function_name = opts[:function_name] || "pgt_cc_#{main_table}__#{main_table_id_column}__#{counter_column}__#{counted_table}__#{counted_table_id_column}"
pgt_trigger(counted_table, trigger_name, function_name, [:insert, :delete], <<-SQL)
BEGIN
IF (TG_OP = 'DELETE') THEN
UPDATE #{quote_schema_table(main_table)} SET #{quote_identifier(counter_column)} = #{quote_identifier(counter_column)} - 1 WHERE #{quote_identifier(main_table_id_column)} = OLD.#{counted_table_id_column};
RETURN OLD;
ELSIF (TG_OP = 'INSERT') THEN
UPDATE #{quote_schema_table(main_table)} SET #{quote_identifier(counter_column)} = #{quote_identifier(counter_column)} + 1 WHERE #{quote_identifier(main_table_id_column)} = NEW.#{quote_identifier(counted_table_id_column)};
RETURN NEW;
END IF;
END;
SQL
end

# Turns a column in the table into a created at timestamp column, which
# always contains the timestamp the record was inserted into the database.
# Arguments:
# * table : name of table
# * column : column in table that should be a created at timestamp column
# * opts : option hash, see module documentation
def pgt_created_at(table, column, opts={})
trigger_name = opts[:trigger_name] || "pgt_ca_#{column}"
function_name = opts[:function_name] || "pgt_ca_#{table}__#{column}"
pgt_trigger(table, trigger_name, function_name, [:insert, :update], <<-SQL)
BEGIN
IF (TG_OP = 'UPDATE') THEN
NEW.#{quote_identifier(column)} := OLD.#{quote_identifier(column)};
ELSIF (TG_OP = 'INSERT') THEN
NEW.#{quote_identifier(column)} := CURRENT_TIMESTAMP;
END IF;
RETURN NEW;
END;
SQL
end

# Makes all given columns in the given table immutable, so an exception
# is raised if there is an attempt to modify the value when updating the
# record. Arguments:
# * table : name of table
# * columns : All columns in the table that should be immutable. Can end with a hash of options, see module documentation.
def pgt_immutable(table, *columns)
opts = columns.extract_options!
trigger_name = opts[:trigger_name] || "pgt_im_#{columns.join('__')}"
function_name = opts[:function_name] || "pgt_im_#{columns.join('__')}"
ifs = columns.map do |c|
old = "OLD.#{quote_identifier(c)}"
new = "NEW.#{quote_identifier(c)}"
<<-END
IF #{new} != #{old} THEN
RAISE EXCEPTION 'Attempted event_id update: Old: %, New: %', #{old}, #{new};
END IF;
END
end.join("\n")
pgt_trigger(table, trigger_name, function_name, :update, "BEGIN #{ifs} RETURN NEW; END;")
end

# Turns a column in the main table into a sum cache. A sum cache is a
# column in the main table with the sum of a column in the summed table
# for the matching id. 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
# * opts : option hash, see module documentation
def pgt_sum_cache(main_table, main_table_id_column, sum_column, summed_table, summed_table_id_column, summed_column, opts={})
trigger_name = opts[:trigger_name] || "pgt_sc_#{main_table}__#{main_table_id_column}__#{sum_column}__#{summed_table_id_column}"
function_name = opts[:function_name] || "pgt_sc_#{main_table}__#{main_table_id_column}__#{sum_column}__#{summed_table}__#{summed_table_id_column}__#{summed_column}"
pgt_trigger(summed_table, trigger_name, function_name, [:insert, :delete, :update], <<-SQL)
BEGIN
IF (TG_OP = 'DELETE') THEN
UPDATE #{quote_schema_table(main_table)} SET #{quote_identifier(sum_column)} = #{quote_identifier(sum_column)} - OLD.#{quote_identifier(summed_column)} WHERE #{quote_identifier(main_table_id_column)} = OLD.#{summed_table_id_column};
RETURN OLD;
ELSIF (TG_OP = 'UPDATE') THEN
UPDATE #{quote_schema_table(main_table)} SET #{quote_identifier(sum_column)} = #{quote_identifier(sum_column)} + NEW.#{quote_identifier(summed_column)} - OLD.#{quote_identifier(summed_column)} WHERE #{quote_identifier(main_table_id_column)} = NEW.#{quote_identifier(summed_table_id_column)};
RETURN NEW;
ELSIF (TG_OP = 'INSERT') THEN
UPDATE #{quote_schema_table(main_table)} SET #{quote_identifier(sum_column)} = #{quote_identifier(sum_column)} + NEW.#{quote_identifier(summed_column)} WHERE #{quote_identifier(main_table_id_column)} = NEW.#{quote_identifier(summed_table_id_column)};
RETURN NEW;
END IF;
END;
SQL
end

# Turns a column in the table into a updated at timestamp column, which
# always contains the timestamp the record was inserted or last updated.
# Arguments:
# * table : name of table
# * column : column in table that should be a updated at timestamp column
# * opts : option hash, see module documentation
def pgt_updated_at(table, column, opts={})
trigger_name = opts[:trigger_name] || "pgt_ua_#{column}"
function_name = opts[:function_name] || "pgt_ua_#{table}__#{column}"
pgt_trigger(table, trigger_name, function_name, [:insert, :update], <<-SQL)
BEGIN
NEW.#{quote_identifier(column)} := CURRENT_TIMESTAMP;
RETURN NEW;
END;
SQL
end

private

# Add or replace a function that returns trigger to handle the action,
# and add a trigger that calls the function.
def pgt_trigger(table, trigger_name, function_name, events, definition)
create_function(function_name, definition, :language=>:plpgsql, :returns=>:trigger, :replace=>true)
create_trigger(table, trigger_name, function_name, :events=>events, :each_row=>true)
end
end
end
end
12 changes: 12 additions & 0 deletions sequel_postgresql_triggers.gemspec
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
spec = Gem::Specification.new do |s|
s.name = "sequel_postgresql_triggers"
s.version = "1.0.0"
s.author = "Jeremy Evans"
s.email = "code@jeremyevans.net"
s.platform = Gem::Platform::RUBY
s.summary = "Database enforced timestamps, immutable columns, and counter/sum caches"
s.files = %w'README LICENSE lib/sequel_postgresql_triggers.rb spec/sequel_postgresql_triggers_spec.rb'
s.require_paths = ["lib"]
s.has_rdoc = true
s.rdoc_options = ['--inline-source', '--line-numbers', '--title', 'Sequel PostgreSQL Triggers: Database enforced timestamps, immutable columns, and counter/sum caches', 'README', 'LICENSE', 'lib']
end
Loading

0 comments on commit ff582a0

Please sign in to comment.