Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with HTTPS or Subversion.

Download ZIP
Browse files

Bring support for modifying joined datasets into Sequel proper, suppo…

…rted on MySQL and PostgreSQL

Previously, the MSSQL adapter had specific support for deleting and
updating joined datasets.  This commit brings support into standard
Sequel, and supports it on MySQL and PostgreSQL. Note that support
and semantics for updating joined datasets varies by database.

This also contains changes to the MSSQL support as well, which should
work better for datasets with multiple FROM tables.

To ease implementation, add a Dataset#joined_dataset? private method.
  • Loading branch information...
commit a71d39d91b743870a317083d7b0c6a49bb72f3da 1 parent edbfbb7
@jeremyevans authored
View
2  CHANGELOG
@@ -1,5 +1,7 @@
=== HEAD
+* Bring support for modifying joined datasets into Sequel proper, supported on MySQL and PostgreSQL (jeremyevans)
+
* No longer use native autoreconnection in the mysql adapter (jeremyevans)
* Add NULL, NOTNULL, TRUE, SQLTRUE, FALSE, and SQLFALSE constants (jeremyevans)
View
39 lib/sequel/adapters/shared/mssql.rb
@@ -323,6 +323,11 @@ def supports_join_using?
false
end
+ # MSSQL 2005+ supports modifying joined datasets
+ def supports_modifying_joins?
+ true
+ end
+
# MSSQL does not support multiple columns for the IN/NOT IN operators
def supports_multiple_column_in?
false
@@ -335,17 +340,26 @@ def supports_window_functions?
private
- # MSSQL can modify joined datasets
- def check_modification_allowed!
- raise(InvalidOperation, "Grouped datasets cannot be modified") if opts[:group]
- end
-
# MSSQL supports the OUTPUT clause for DELETE statements.
# It also allows prepending a WITH clause.
def delete_clause_methods
DELETE_CLAUSE_METHODS
end
+ # Only include the primary table in the main delete clause
+ def delete_from_sql(sql)
+ sql << " FROM #{source_list(@opts[:from][0..0])}"
+ end
+
+ # MSSQL supports FROM clauses in DELETE and UPDATE statements.
+ def delete_from2_sql(sql)
+ if joined_dataset?
+ select_from_sql(sql)
+ select_join_sql(sql)
+ end
+ end
+ alias update_from_sql delete_from2_sql
+
# Handle the with clause for delete, insert, and update statements
# to be the same as the insert statement.
def delete_with_sql(sql)
@@ -361,16 +375,6 @@ def format_timestamp_usec(usec)
sprintf(".%03d", usec/1000)
end
- # MSSQL supports FROM clauses in DELETE and UPDATE statements.
- def from_sql(sql)
- if (opts[:from].is_a?(Array) && opts[:from].size > 1) || opts[:join]
- select_from_sql(sql)
- select_join_sql(sql)
- end
- end
- alias delete_from2_sql from_sql
- alias update_from_sql from_sql
-
# MSSQL supports the OUTPUT clause for INSERT statements.
# It also allows prepending a WITH clause.
def insert_clause_methods
@@ -441,6 +445,11 @@ def output_sql(sql)
def update_clause_methods
UPDATE_CLAUSE_METHODS
end
+
+ # Only include the primary table in the main update clause
+ def update_table_sql(sql)
+ sql << " #{source_list(@opts[:from][0..0])}"
+ end
end
end
end
View
5 lib/sequel/adapters/shared/mysql.rb
@@ -327,6 +327,11 @@ def supports_intersect_except?
false
end
+ # MySQL supports modifying joined datasets
+ def supports_modifying_joins?
+ true
+ end
+
# MySQL does support fractional timestamps in literal timestamps, but it
# ignores them. Also, using them seems to cause problems on 1.9. Since
# they are ignored anyway, not using them is probably best.
View
48 lib/sequel/adapters/shared/postgres.rb
@@ -588,6 +588,7 @@ module DatasetMethods
BOOL_FALSE = 'false'.freeze
BOOL_TRUE = 'true'.freeze
COMMA_SEPARATOR = ', '.freeze
+ DELETE_CLAUSE_METHODS = Dataset.clause_methods(:delete, %w'from using where')
EXCLUSIVE = 'EXCLUSIVE'.freeze
EXPLAIN = 'EXPLAIN '.freeze
EXPLAIN_ANALYZE = 'EXPLAIN ANALYZE '.freeze
@@ -605,6 +606,7 @@ module DatasetMethods
SHARE_ROW_EXCLUSIVE = 'SHARE ROW EXCLUSIVE'.freeze
SHARE_UPDATE_EXCLUSIVE = 'SHARE UPDATE EXCLUSIVE'.freeze
SQL_WITH_RECURSIVE = "WITH RECURSIVE ".freeze
+ UPDATE_CLAUSE_METHODS = Dataset.clause_methods(:update, %w'table set from where')
# Shared methods for prepared statements when used with PostgreSQL databases.
module PreparedStatementMethods
@@ -706,6 +708,11 @@ def multi_insert_sql(columns, values)
[insert_sql(columns, LiteralString.new('VALUES ' + values.map {|r| literal(Array(r))}.join(COMMA_SEPARATOR)))]
end
+ # PostgreSQL supports modifying joined datasets
+ def supports_modifying_joins?
+ true
+ end
+
# PostgreSQL supports timezones in literal timestamps
def supports_timestamp_timezones?
true
@@ -723,12 +730,38 @@ def window(name, opts)
private
+ # PostgreSQL allows deleting from joined datasets
+ def delete_clause_methods
+ DELETE_CLAUSE_METHODS
+ end
+
+ # Only include the primary table in the main delete clause
+ def delete_from_sql(sql)
+ sql << " FROM #{source_list(@opts[:from][0..0])}"
+ end
+
+ # Use USING to specify additional tables in a delete query
+ def delete_using_sql(sql)
+ join_from_sql(:USING, sql)
+ end
+
# Use the RETURNING clause to return the primary key of the inserted record, if it exists
def insert_returning_pk_sql(*values)
pk = db.primary_key(opts[:from].first) if opts[:from] && !opts[:from].empty?
insert_returning_sql(pk ? Sequel::SQL::Identifier.new(pk) : NULL, *values)
end
+ # For multiple table support, PostgreSQL requires at least
+ # two from tables, with joins allowed.
+ def join_from_sql(type, sql)
+ if(from = @opts[:from][1..-1]).empty?
+ raise(Error, 'Need multiple FROM tables if updating/deleting a dataset with JOINs') if @opts[:join]
+ else
+ sql << " #{type} #{source_list(from)}"
+ select_join_sql(sql)
+ end
+ end
+
# Use a generic blob quoting method, hopefully overridden in one of the subadapter methods
def literal_blob(v)
"'#{v.gsub(/[\000-\037\047\134\177-\377]/){|b| "\\#{("%o" % b[0..1].unpack("C")[0]).rjust(3, '0')}"}}'"
@@ -786,6 +819,21 @@ def full_text_string_join(cols)
cols.pop
literal(SQL::StringExpression.new(:'||', *cols))
end
+
+ # PostgreSQL splits the main table from the joined tables
+ def update_clause_methods
+ UPDATE_CLAUSE_METHODS
+ end
+
+ # Use FROM to specify additional tables in an update query
+ def update_from_sql(sql)
+ join_from_sql(:FROM, sql)
+ end
+
+ # Only include the primary table in the main update clause
+ def update_table_sql(sql)
+ sql << " #{source_list(@opts[:from][0..0])}"
+ end
end
end
end
View
5 lib/sequel/dataset/features.rb
@@ -41,6 +41,11 @@ def supports_join_using?
true
end
+ # Whether modifying joined datasets is supported.
+ def supports_modifying_joins?
+ false
+ end
+
# Whether the IN/NOT IN operators support multiple columns when an
# array of values is given.
def supports_multiple_column_in?
View
18 lib/sequel/dataset/sql.rb
@@ -653,7 +653,7 @@ def as_sql(expression, aliaz)
# for this dataset
def check_modification_allowed!
raise(InvalidOperation, "Grouped datasets cannot be modified") if opts[:group]
- raise(InvalidOperation, "Joined datasets cannot be modified") if (opts[:from].is_a?(Array) && opts[:from].size > 1) || opts[:join]
+ raise(InvalidOperation, "Joined datasets cannot be modified") if !supports_modifying_joins? && joined_dataset?
end
# Prepare an SQL statement by calling all clause methods for the given statement type.
@@ -679,6 +679,12 @@ def delete_clause_methods
DELETE_CLAUSE_METHODS
end
+ # Included both from a join tables if modifying joins is allowed
+ def delete_from_sql(sql)
+ select_from_sql(sql)
+ select_join_sql(sql) if supports_modifying_joins?
+ end
+
# Converts an array of expressions into a comma separated string of
# expressions.
def expression_list(columns)
@@ -764,6 +770,11 @@ def join_type_sql(join_type)
"#{join_type.to_s.gsub('_', ' ').upcase} JOIN"
end
+ # Whether this dataset is a joined dataset
+ def joined_dataset?
+ (opts[:from].is_a?(Array) && opts[:from].size > 1) || opts[:join]
+ end
+
# SQL fragment for Array. Treats as an expression if an array of all two pairs, or as a SQL array otherwise.
def literal_array(v)
Sequel.condition_specifier?(v) ? literal_expression(SQL::BooleanExpression.from_value_pairs(v)) : array_sql(v)
@@ -973,7 +984,6 @@ def select_compounds_sql(sql)
def select_from_sql(sql)
sql << " FROM #{source_list(@opts[:from])}" if @opts[:from]
end
- alias delete_from_sql select_from_sql
# Modify the sql to add the expressions to GROUP BY
def select_group_sql(sql)
@@ -1068,9 +1078,11 @@ def update_clause_methods
UPDATE_CLAUSE_METHODS
end
- # SQL fragment specifying the tables from with to delete
+ # SQL fragment specifying the tables from with to delete.
+ # Includes join table if modifying joins is allowed.
def update_table_sql(sql)
sql << " #{source_list(@opts[:from])}"
+ select_join_sql(sql) if supports_modifying_joins?
end
# The SQL fragment specifying the columns and values to SET.
View
4 spec/adapters/postgres_spec.rb
@@ -147,6 +147,10 @@ def logger.method_missing(m, msg)
@d.lock('EXCLUSIVE'){@d.insert(:name=>'a')}.should == nil
POSTGRES_DB.transaction{@d.lock('EXCLUSIVE').should == nil; @d.insert(:name=>'a')}
end
+
+ specify "should raise an error if attempting to update a joined dataset with a single FROM table" do
+ proc{POSTGRES_DB[:test].join(:test2, [:name]).update(:name=>'a')}.should raise_error(Sequel::Error, 'Need multiple FROM tables if updating/deleting a dataset with JOINs')
+ end
end
context "A PostgreSQL dataset with a timestamp field" do
View
18 spec/core/dataset_spec.rb
@@ -3554,3 +3554,21 @@ def @ds.fetch_rows(sql)
@ds.db.sqls.should == ['SELECT t.c AS a, t.d AS b FROM t']
end
end
+
+context "Modifying joined datasets" do
+ before do
+ @ds = MockDatabase.new.from(:b, :c).join(:d, [:id]).where(:id => 2)
+ @ds.meta_def(:supports_modifying_joins?){true}
+ @ds.db.reset
+ end
+
+ specify "should allow deleting from joined datasets" do
+ @ds.delete
+ @ds.db.sqls.should == ['DELETE FROM b, c INNER JOIN d USING (id) WHERE (id = 2)']
+ end
+
+ specify "should allow updating joined datasets" do
+ @ds.update(:a=>1)
+ @ds.db.sqls.should == ['UPDATE b, c INNER JOIN d USING (id) SET a = 1 WHERE (id = 2)']
+ end
+end
View
35 spec/integration/dataset_test.rb
@@ -870,3 +870,38 @@ def uprev
@ds.all.should == [{:a=>10}, {:a=>10}]
end
end
+
+if INTEGRATION_DB.dataset.supports_modifying_joins?
+ describe "Modifying joined datasets" do
+ before do
+ @db = INTEGRATION_DB
+ @db.create_table!(:a){Integer :a; Integer :d}
+ @db.create_table!(:b){Integer :b}
+ @db.create_table!(:c){Integer :c}
+ @ds = @db.from(:a, :b).join(:c, :c=>:b.identifier).where(:d=>:b).order(:a)
+ @db[:a].insert(1, 2)
+ @db[:a].insert(3, 4)
+ @db[:b].insert(2)
+ @db[:c].insert(2)
+ end
+ after do
+ @db.drop_table(:a, :b, :c)
+ end
+
+ it "#update should allow updating joined datasets" do
+ @ds.update(:a=>10)
+ @ds.all.should == [{:c=>2, :b=>2, :a=>10, :d=>2}]
+ @db[:a].order(:a).all.should == [{:a=>3, :d=>4}, {:a=>10, :d=>2}]
+ @db[:b].all.should == [{:b=>2}]
+ @db[:c].all.should == [{:c=>2}]
+ end
+
+ it "#delete should allow deleting from joined datasets" do
+ @ds.delete
+ @ds.all.should == []
+ @db[:a].order(:a).all.should == [{:a=>3, :d=>4}]
+ @db[:b].all.should == [{:b=>2}]
+ @db[:c].all.should == [{:c=>2}]
+ end
+ end
+end
Please sign in to comment.
Something went wrong with that request. Please try again.