Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with HTTPS or Subversion.

Download ZIP
Browse files

Support transaction isolation levels on PostgreSQL, MySQL, and MSSQL

Transaction isolation levels are a way to specify how visible
outside changes are to a running transaction.  Sequel previously
did not have the ability to specify which transaction isolation
level to use, which means the database's default was always used.

This commit adds support for an :isolation option to
Database#transaction, which will modify the isolation level to
use for the transaction.  It also adds a
transaction_isolation_level Database attr_accessor, which specifies
the default transaction isolation level if one is not given via
the :isolation option.  On MSSQL, it's recommended that if you
ever use the :isolation option, you also set the
transaction_isolation_level attribute, as MSSQL transaction
isolation levels are per connection, not transaction.

The four transaction isolation levels supported by PostgreSQL,
MySQL, and MSSQL are :uncommitted, :committed, :repeatable,
and :serializable, for READ UNCOMMITTED, READ COMMITTED,
REPEATABLE READ, and SERIALIZABLE.

I looked into support for Oracle, Firebird, SQLite, and H2,
but while all of them have similar options, I don't test on
Oracle or Firebird, and SQLite and H2 transaction isolation
level support is substantially different from the SQL
standard to support using a separate API (which may be added if
requested).
  • Loading branch information...
commit 6e967a2be8176bcffcdcbec93ef07c365eb8eab9 1 parent fa8c9bb
@jeremyevans authored
View
2  CHANGELOG
@@ -1,5 +1,7 @@
=== HEAD
+* Support transaction isolation levels on PostgreSQL, MySQL, and MSSQL (jeremyevans)
+
* Support prepared transactions/two-phase commit on PostgreSQL, MySQL, and H2 (jeremyevans)
* Allow NULLS FIRST/LAST when ordering using the :nulls=>:first/:last option to asc and desc (jeremyevans)
View
5 lib/sequel/adapters/shared/mssql.rb
@@ -39,6 +39,11 @@ def supports_savepoints?
true
end
+ # MSSQL supports transaction isolation levels
+ def supports_transaction_isolation_levels?
+ true
+ end
+
# Microsoft SQL Server supports using the INFORMATION_SCHEMA to get
# information on tables.
def tables(opts={})
View
11 lib/sequel/adapters/shared/mysql.rb
@@ -89,6 +89,11 @@ def supports_savepoints?
true
end
+ # MySQL supports transaction isolation levels
+ def supports_transaction_isolation_levels?
+ true
+ end
+
# Changes the database in use by issuing a USE statement. I would be
# very careful if I used this.
def use(db_name)
@@ -134,6 +139,12 @@ def auto_increment_sql
AUTO_INCREMENT
end
+ # MySQL needs to set transaction isolation before begining a transaction
+ def begin_new_transaction(conn, opts)
+ set_transaction_isolation(conn, opts)
+ log_connection_execute(conn, begin_transaction_sql)
+ end
+
# Use XA START to start a new prepared transaction if the :prepare
# option is given.
def begin_transaction(conn, opts={})
View
5 lib/sequel/adapters/shared/postgres.rb
@@ -362,6 +362,11 @@ def supports_savepoints?
true
end
+ # PostgreSQL supports transaction isolation levels
+ def supports_transaction_isolation_levels?
+ true
+ end
+
# Whether the given table exists in the database
#
# Options:
View
5 lib/sequel/database/misc.rb
@@ -90,6 +90,11 @@ def supports_savepoints?
false
end
+ # Whether the database and adapter support transaction isolation levels, false by default
+ def supports_transaction_isolation_levels?
+ false
+ end
+
# Typecast the value to the given column_type. Calls
# typecast_value_#{column_type} if the method exists,
# otherwise returns the value.
View
43 lib/sequel/database/query.rb
@@ -15,6 +15,11 @@ class Database
TRANSACTION_BEGIN = 'Transaction.begin'.freeze
TRANSACTION_COMMIT = 'Transaction.commit'.freeze
TRANSACTION_ROLLBACK = 'Transaction.rollback'.freeze
+
+ TRANSACTION_ISOLATION_LEVELS = {:uncommitted=>'READ UNCOMMITTED'.freeze,
+ :committed=>'READ COMMITTED'.freeze,
+ :repeatable=>'REPEATABLE READ'.freeze,
+ :serializable=>'SERIALIZABLE'.freeze}
POSTGRES_DEFAULT_RE = /\A(?:B?('.*')::[^']+|\((-?\d+(?:\.\d+)?)\))\z/
MSSQL_DEFAULT_RE = /\A(?:\(N?('.*')\)|\(\((-?\d+(?:\.\d+)?)\)\))\z/
@@ -24,6 +29,13 @@ class Database
# The prepared statement objects for this database, keyed by name
attr_reader :prepared_statements
+ # The default transaction isolation level for this database,
+ # used for all future transactions. For MSSQL, this should be set
+ # to something if you ever plan to use the :isolation option to
+ # Database#transaction, as on MSSQL if affects all future transactions
+ # on the same connection.
+ attr_accessor :transaction_isolation_level
+
# Runs the supplied SQL statement string on the database server.
# Alias for run.
def <<(sql)
@@ -142,6 +154,8 @@ def tables(opts={})
#
# The following options are respected:
#
+ # :isolation :: The transaction isolation level to use for this transaction,
+ # should be :uncommitted, :committed, :repeatable, or :serializable.
# :prepare :: A string to use as the transaction identifier for a
# prepared transaction (two-phase commit), if the database/adapter
# supports prepared transactions
@@ -205,15 +219,24 @@ def begin_savepoint_sql(depth)
SQL_SAVEPOINT % depth
end
- # Start a new database transaction on the given connection.
+ # Start a new database connection on the given connection
+ def begin_new_transaction(conn, opts)
+ log_connection_execute(conn, begin_transaction_sql)
+ set_transaction_isolation(conn, opts)
+ end
+
+ # Start a new database transaction or a new savepoint on the given connection.
def begin_transaction(conn, opts={})
if supports_savepoints?
th = Thread.current
- depth = th[:sequel_transaction_depth]
- log_connection_execute(conn, depth > 0 ? begin_savepoint_sql(depth) : begin_transaction_sql)
+ if (depth = th[:sequel_transaction_depth]) > 0
+ log_connection_execute(conn, begin_savepoint_sql(depth))
+ else
+ begin_new_transaction(conn, opts)
+ end
th[:sequel_transaction_depth] += 1
else
- log_connection_execute(conn, begin_transaction_sql)
+ begin_new_transaction(conn, opts)
end
conn
end
@@ -385,6 +408,18 @@ def schema_column_type(db_type)
end
end
+ # Set the transaction isolation level on the given connection
+ def set_transaction_isolation(conn, opts)
+ if supports_transaction_isolation_levels? and level = opts.fetch(:isolation, transaction_isolation_level)
+ log_connection_execute(conn, set_transaction_isolation_sql(level))
+ end
+ end
+
+ # SQL to set the transaction isolation level
+ def set_transaction_isolation_sql(level)
+ "SET TRANSACTION ISOLATION LEVEL #{TRANSACTION_ISOLATION_LEVELS[level]}"
+ end
+
# Raise a database error unless the exception is an Rollback.
def transaction_error(e)
raise_error(e, :classes=>database_error_classes) unless e.is_a?(Rollback)
View
31 spec/core/database_spec.rb
@@ -695,10 +695,33 @@ def execute(sql); @db.execute(sql); end
end
specify "should wrap the supplied block with BEGIN + COMMIT statements" do
- @db.transaction {@db.execute 'DROP TABLE test;'}
+ @db.transaction{@db.execute 'DROP TABLE test;'}
@db.sql.should == ['BEGIN', 'DROP TABLE test;', 'COMMIT']
end
+ specify "should support transaction isolation levels" do
+ @db.meta_def(:supports_transaction_isolation_levels?){true}
+ [:uncommitted, :committed, :repeatable, :serializable].each do |l|
+ @db.transaction(:isolation=>l){@db.run "DROP TABLE #{l}"}
+ end
+ @db.sql.should == ['BEGIN', 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED', 'DROP TABLE uncommitted', 'COMMIT',
+ 'BEGIN', 'SET TRANSACTION ISOLATION LEVEL READ COMMITTED', 'DROP TABLE committed', 'COMMIT',
+ 'BEGIN', 'SET TRANSACTION ISOLATION LEVEL REPEATABLE READ', 'DROP TABLE repeatable', 'COMMIT',
+ 'BEGIN', 'SET TRANSACTION ISOLATION LEVEL SERIALIZABLE', 'DROP TABLE serializable', 'COMMIT']
+ end
+
+ specify "should allow specifying a default transaction isolation level" do
+ @db.meta_def(:supports_transaction_isolation_levels?){true}
+ [:uncommitted, :committed, :repeatable, :serializable].each do |l|
+ @db.transaction_isolation_level = l
+ @db.transaction{@db.run "DROP TABLE #{l}"}
+ end
+ @db.sql.should == ['BEGIN', 'SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED', 'DROP TABLE uncommitted', 'COMMIT',
+ 'BEGIN', 'SET TRANSACTION ISOLATION LEVEL READ COMMITTED', 'DROP TABLE committed', 'COMMIT',
+ 'BEGIN', 'SET TRANSACTION ISOLATION LEVEL REPEATABLE READ', 'DROP TABLE repeatable', 'COMMIT',
+ 'BEGIN', 'SET TRANSACTION ISOLATION LEVEL SERIALIZABLE', 'DROP TABLE serializable', 'COMMIT']
+ end
+
specify "should handle returning inside of the block by committing" do
def @db.ret_commit
transaction do
@@ -1589,6 +1612,12 @@ def @db.disconnect_connection(c)
end
end
+context "Database#supports_transaction_isolation_levels?" do
+ specify "should be false by default" do
+ Sequel::Database.new.supports_transaction_isolation_levels?.should == false
+ end
+end
+
context "Database#input_identifier_meth" do
specify "should be the input_identifer method of a default dataset for this database" do
db = Sequel::Database.new
View
7 spec/integration/transaction_test.rb
@@ -127,4 +127,11 @@ def @db.ret_commit
@d.select_order_map(:name).should == []
end
end
+
+ specify "should support all transaction isolation levels" do
+ [:uncommitted, :committed, :repeatable, :serializable].each_with_index do |l, i|
+ @db.transaction(:isolation=>l){@d << {:name => 'abc', :value => 1}}
+ @d.count.should == i + 1
+ end
+ end
end
Please sign in to comment.
Something went wrong with that request. Please try again.