Permalink
Browse files

Add Dataset#for_update as a standard dataset method

Previously, Sequel only supported FOR UPDATE on PostgreSQL. This
commit adds support for all databases, and has been tested on
PostgreSQL, MySQL, SQLite (where it is ignored), H2, and MSSQL.

Sequel's PostgreSQL adapter also supports for_share, but because
it seems that most databases don't implement something similar,
I chose not to add it as one of the standard dataset methods. I
did add it to the MySQL adapter, where it uses LOCK IN SHARE MODE.
I'm not sure if FOR SHARE on PostgreSQL is equivalent to LOCK IN
SHARE MODE on MySQL, but considering that there are already
substantial differences in how FOR UPDATE is handled, it's
probably not a big deal.

New to Sequel is Dataset#lock_style, which returns a cloned
dataset with the given lock style, which can be either a symbol
or a string.  If a symbol and the symbol is recognized by the
adapter, the appropriate locking style will be used for the query
(most adapters only support :update).  If a string, it is treated
as a literal string.

The MSSQL shared adapter changed from using :table_options to
using :lock as the internal option name.  If you were using
:table_options manually, you'll need to switch to using :lock
and include the starting WITH.  Dataset#nolock on MSSQL was
changed to use the new lock_style method.
  • Loading branch information...
1 parent d3e131a commit e8934fc845d7c9be5148de96ee432c0e0b27ced9 @jeremyevans committed Mar 9, 2010
View
@@ -1,5 +1,7 @@
=== HEAD
+* Add Dataset#for_update as a standard dataset method (jeremyevans)
+
* Add composition plugin, simlar to ActiveRecord's composed_of (jeremyevans)
* Combine multiple complex expressions for simpler SQL and object tree (jeremyevans)
@@ -183,8 +183,10 @@ module DatasetMethods
COMMA_SEPARATOR = ', '.freeze
DELETE_CLAUSE_METHODS = Dataset.clause_methods(:delete, %w'with from output from2 where')
INSERT_CLAUSE_METHODS = Dataset.clause_methods(:insert, %w'with into columns output values')
- SELECT_CLAUSE_METHODS = Dataset.clause_methods(:select, %w'with limit distinct columns into from table_options join where group having order compounds')
+ SELECT_CLAUSE_METHODS = Dataset.clause_methods(:select, %w'with limit distinct columns into from lock join where group having order compounds')
UPDATE_CLAUSE_METHODS = Dataset.clause_methods(:update, %w'with table set output from where')
+ NOLOCK = ' WITH (NOLOCK)'.freeze
+ UPDLOCK = ' WITH (UPDLOCK)'.freeze
WILDCARD = LiteralString.new('*').freeze
CONSTANT_MAP = {:CURRENT_DATE=>'CAST(CURRENT_TIMESTAMP AS DATE)'.freeze, :CURRENT_TIME=>'CAST(CURRENT_TIMESTAMP AS TIME)'.freeze}
@@ -244,9 +246,9 @@ def multi_insert_sql(columns, values)
[insert_sql(columns, LiteralString.new(values.map {|r| "SELECT #{expression_list(r)}" }.join(" UNION ALL ")))]
end
- # Allows you to do .nolock on a query
+ # Allows you to do a dirty read of uncommitted data using WITH (NOLOCK).
def nolock
- clone(:table_options => "(NOLOCK)")
+ lock_style(:dirty)
end
# Include an OUTPUT clause in the eventual INSERT, UPDATE, or DELETE query.
@@ -433,9 +435,16 @@ def select_limit_sql(sql)
sql << " TOP (#{literal(@opts[:limit])})" if @opts[:limit]
end
- # MSSQL uses the WITH statement to lock tables
- def select_table_options_sql(sql)
- sql << " WITH #{@opts[:table_options]}" if @opts[:table_options]
+ # Support different types of locking styles
+ def select_lock_sql(sql)
+ case @opts[:lock]
+ when :update
+ sql << UPDLOCK
+ when :dirty
+ sql << NOLOCK
+ else
+ super
+ end
end
# SQL fragment for MSSQL's OUTPUT clause.
@@ -227,9 +227,10 @@ module DatasetMethods
BOOL_TRUE = '1'.freeze
BOOL_FALSE = '0'.freeze
COMMA_SEPARATOR = ', '.freeze
+ FOR_SHARE = ' LOCK IN SHARE MODE'.freeze
DELETE_CLAUSE_METHODS = Dataset.clause_methods(:delete, %w'from where order limit')
INSERT_CLAUSE_METHODS = Dataset.clause_methods(:insert, %w'ignore into columns values on_duplicate_key_update')
- SELECT_CLAUSE_METHODS = Dataset.clause_methods(:select, %w'distinct columns from join where group having compounds order limit')
+ SELECT_CLAUSE_METHODS = Dataset.clause_methods(:select, %w'distinct columns from join where group having compounds order limit lock')
UPDATE_CLAUSE_METHODS = Dataset.clause_methods(:update, %w'table set where order limit')
# MySQL specific syntax for LIKE/REGEXP searches, as well as
@@ -248,6 +249,11 @@ def complex_expression_sql(op, args)
super(op, args)
end
end
+
+ # Return a cloned dataset which will use LOCK IN SHARE MODE to lock returned rows.
+ def for_share
+ lock_style(:share)
+ end
# Adds full text filter
def full_text_search(cols, terms, opts = {})
@@ -465,6 +471,11 @@ def on_duplicate_key_update_sql
def select_clause_methods
SELECT_CLAUSE_METHODS
end
+
+ # Support FOR SHARE locking when using the :share lock style.
+ def select_lock_sql(sql)
+ @opts[:lock] == :share ? (sql << FOR_SHARE) : super
+ end
# MySQL supports the ORDER BY and LIMIT clauses for UPDATE statements
def update_clause_methods
@@ -593,7 +593,6 @@ module DatasetMethods
EXPLAIN = 'EXPLAIN '.freeze
EXPLAIN_ANALYZE = 'EXPLAIN ANALYZE '.freeze
FOR_SHARE = ' FOR SHARE'.freeze
- FOR_UPDATE = ' FOR UPDATE'.freeze
LOCK = 'LOCK TABLE %s IN %s MODE'.freeze
NULL = LiteralString.new('NULL').freeze
PG_TIMESTAMP_FORMAT = "TIMESTAMP '%Y-%m-%d %H:%M:%S".freeze
@@ -647,14 +646,9 @@ def explain(opts={})
with_sql((opts[:analyze] ? EXPLAIN_ANALYZE : EXPLAIN) + select_sql).map(QUERY_PLAN).join("\r\n")
end
- # Return a cloned dataset with a :share lock type.
+ # Return a cloned dataset which will use FOR SHARE to lock returned rows.
def for_share
- clone(:lock => :share)
- end
-
- # Return a cloned dataset with a :update lock type.
- def for_update
- clone(:lock => :update)
+ lock_style(:share)
end
# PostgreSQL specific full text search syntax, using tsearch2 (included
@@ -786,21 +780,16 @@ def literal_true
def select_clause_methods
server_version >= 80400 ? SELECT_CLAUSE_METHODS_84 : SELECT_CLAUSE_METHODS
end
+
+ # Support FOR SHARE locking when using the :share lock style.
+ def select_lock_sql(sql)
+ @opts[:lock] == :share ? (sql << FOR_SHARE) : super
+ end
# SQL fragment for named window specifications
def select_window_sql(sql)
sql << " WINDOW #{@opts[:window].map{|name, window| "#{literal(name)} AS #{literal(window)}"}.join(', ')}" if @opts[:window]
end
-
- # Support lock mode, allowing FOR SHARE and FOR UPDATE queries.
- def select_lock_sql(sql)
- case @opts[:lock]
- when :update
- sql << FOR_UPDATE
- when :share
- sql << FOR_SHARE
- end
- end
# Use WITH RECURSIVE instead of WITH if any of the CTEs is recursive
def select_with_sql_base
@@ -329,6 +329,11 @@ def select_clause_methods
SELECT_CLAUSE_METHODS
end
+ # Support FOR SHARE locking when using the :share lock style.
+ def select_lock_sql(sql)
+ super unless @opts[:lock] == :update
+ end
+
# SQLite treats a DELETE with no WHERE clause as a TRUNCATE
def _truncate_sql(table)
"DELETE FROM #{table}"
@@ -104,6 +104,11 @@ def exclude(*cond, &block)
def filter(*cond, &block)
_filter(@opts[:having] ? :having : :where, *cond, &block)
end
+
+ # Returns a cloned dataset with a :update lock style.
+ def for_update
+ lock_style(:update)
+ end
# Returns a copy of the dataset with the source changed.
#
@@ -236,6 +241,14 @@ def limit(l, o = nil)
clone(opts)
end
+ # Returns a cloned dataset with the given lock style. If style is a
+ # string, it will be used directly. Otherwise, a symbol may be used
+ # for database independent locking. Currently :update is respected
+ # by most databases, and :share is supported by some.
+ def lock_style(style)
+ clone(:lock => style)
+ end
+
# Adds an alternate filter to an existing filter using OR. If no filter
# exists an error is raised.
#
@@ -25,6 +25,7 @@ def self.clause_methods(type, clauses)
COLUMN_REF_RE3 = /\A([\w ]+)__([\w ]+)\z/.freeze
COUNT_FROM_SELF_OPTS = [:distinct, :group, :sql, :limit, :compounds]
DATASET_ALIAS_BASE_NAME = 't'.freeze
+ FOR_UPDATE = ' FOR UPDATE'.freeze
IS_LITERALS = {nil=>'NULL'.freeze, true=>'TRUE'.freeze, false=>'FALSE'.freeze}.freeze
IS_OPERATORS = ::Sequel::SQL::ComplexExpression::IS_OPERATORS
N_ARITY_OPERATORS = ::Sequel::SQL::ComplexExpression::N_ARITY_OPERATORS
@@ -33,7 +34,7 @@ def self.clause_methods(type, clauses)
QUESTION_MARK = '?'.freeze
DELETE_CLAUSE_METHODS = clause_methods(:delete, %w'from where')
INSERT_CLAUSE_METHODS = clause_methods(:insert, %w'into columns values')
- SELECT_CLAUSE_METHODS = clause_methods(:select, %w'with distinct columns from join where group having compounds order limit')
+ SELECT_CLAUSE_METHODS = clause_methods(:select, %w'with distinct columns from join where group having compounds order limit lock')
UPDATE_CLAUSE_METHODS = clause_methods(:update, %w'table set where')
TIMESTAMP_FORMAT = "'%Y-%m-%d %H:%M:%S%N%z'".freeze
STANDARD_TIMESTAMP_FORMAT = "TIMESTAMP #{TIMESTAMP_FORMAT}".freeze
@@ -1093,6 +1094,16 @@ def select_limit_sql(sql)
sql << " LIMIT #{literal(@opts[:limit])}" if @opts[:limit]
sql << " OFFSET #{literal(@opts[:offset])}" if @opts[:offset]
end
+
+ # Modify the sql to support the different types of locking modes.
+ def select_lock_sql(sql)
+ case @opts[:lock]
+ when :update
+ sql << FOR_UPDATE
+ when String
+ sql << @opts[:lock]
+ end
+ end
# Modify the sql to add the expressions to ORDER BY
def select_order_sql(sql)
@@ -53,6 +53,10 @@ def logger.method_missing(m, msg)
proc{@db.server_version}.should_not raise_error
proc{@db.dataset.server_version}.should_not raise_error
end
+
+ specify "should work with NOLOCK" do
+ @db.transaction{@db[:test3].nolock.all.should == []}
+ end
end
context "MSSQL Dataset#join_table" do
@@ -83,6 +83,10 @@ def logger.method_missing(m, msg)
specify "should handle the creation and dropping of an InnoDB table with foreign keys" do
proc{MYSQL_DB.create_table!(:test_innodb, :engine=>:InnoDB){primary_key :id; foreign_key :fk, :test_innodb, :key=>:id}}.should_not raise_error
end
+
+ specify "should support for_share" do
+ MYSQL_DB.transaction{MYSQL_DB[:test2].for_share.all.should == []}
+ end
end
if MYSQL_DB.class.adapter_scheme == :mysql
@@ -130,11 +130,6 @@ def logger.method_missing(m, msg)
@d.filter(:name => /^bc/).count.should == 1
end
- specify "should support for_share and for_update" do
- @d.for_share.all.should == []
- @d.for_update.all.should == []
- end
-
specify "#lock should lock tables and yield if a block is given" do
@d.lock('EXCLUSIVE'){@d.insert(:name=>'a')}
end
@@ -153,6 +148,61 @@ def logger.method_missing(m, msg)
end
end
+if POSTGRES_DB.pool.respond_to?(:max_size) and POSTGRES_DB.pool.max_size > 1
+ describe "Dataset#for_update support" do
+ before do
+ @db = POSTGRES_DB.create_table!(:items) do
+ primary_key :id
+ Integer :number
+ String :name
+ end
+ @ds = POSTGRES_DB[:items]
+ clear_sqls
+ end
+ after do
+ POSTGRES_DB.drop_table(:items)
+ POSTGRES_DB.disconnect
+ end
+
+ specify "should handle FOR UPDATE" do
+ @ds.insert(:number=>20)
+ c = nil
+ t = nil
+ POSTGRES_DB.transaction do
+ @ds.for_update.first(:id=>1)
+ t = Thread.new do
+ POSTGRES_DB.transaction do
+ @ds.filter(:id=>1).update(:name=>'Jim')
+ c = @ds.first(:id=>1)
+ end
+ end
+ sleep 0.01
+ @ds.filter(:id=>1).update(:number=>30)
+ end
+ t.join
+ c.should == {:id=>1, :number=>30, :name=>'Jim'}
+ end
+
+ specify "should handle FOR SHARE" do
+ @ds.insert(:number=>20)
+ c = nil
+ t = nil
+ POSTGRES_DB.transaction do
+ @ds.for_share.first(:id=>1)
+ t = Thread.new do
+ POSTGRES_DB.transaction do
+ c = @ds.for_share.filter(:id=>1).first
+ end
+ end
+ sleep 0.05
+ @ds.filter(:id=>1).update(:name=>'Jim')
+ c.should == {:id=>1, :number=>20, :name=>nil}
+ end
+ t.join
+ end
+ end
+end
+
context "A PostgreSQL dataset with a timestamp field" do
before do
@d = POSTGRES_DB[:test3]
@@ -266,6 +266,10 @@
@ds.order(:id).all.should == [{:id=>1, :number=>20}]
end
end
+
+ specify "should support for_update" do
+ INTEGRATION_DB.transaction{@ds.for_update.all.should == []}
+ end
end
describe "Dataset UNION, EXCEPT, and INTERSECT" do
@@ -596,7 +600,7 @@
@ds.filter("b < ?", 15).invert.all.should == [{:a=>20, :b=>30}]
end
- it "#and and #or should work with placeholder strings" do
+ it "#and and #or should work correctly" do
@ds.insert(20, 30)
@ds.filter(:a=>20).and(:b=>30).all.should == [{:a=>20, :b=>30}]
@ds.filter(:a=>20).and(:b=>15).all.should == []

0 comments on commit e8934fc

Please sign in to comment.