Permalink
Browse files

Allow NULLS FIRST/LAST when ordering using the :nulls=>:first/:last o…

…ption to asc and desc

NULLS FIRST/LAST is an SQL:2003 extension supported by PostgreSQL
8.3+, Firebird 1.5+, Oracle, and probably some other databases
as well.  As you might expect, NULLS FIRST makes NULL values show
up before other values, and NULLS LAST makes NULL values show up
after other values.

In Sequel, this feature is exposed via the new :nulls option to
asc and desc:

  ds.filter(:release_date.desc(:nulls=>:first),
            :name.asc(:nulls=>:last))

Sequel can correctly invert orders even when the :nulls option is
used, switching ASC NULLS FIRST to DESC NULLS LAST, for example.
  • Loading branch information...
jeremyevans committed Jun 21, 2010
1 parent b33a367 commit b9383700d884e25c63fde2eb53e10a7a2323dc54
Showing with 53 additions and 10 deletions.
  1. +2 −0 CHANGELOG
  2. +9 −1 lib/sequel/dataset/sql.rb
  3. +23 −9 lib/sequel/sql.rb
  4. +9 −0 spec/adapters/postgres_spec.rb
  5. +10 −0 spec/core/dataset_spec.rb
View
@@ -1,5 +1,7 @@
=== HEAD
+* Allow NULLS FIRST/LAST when ordering using the :nulls=>:first/:last option to asc and desc (jeremyevans)
+
* On PostgreSQL, if no :schema option is provided for #tables, #table_exists?, or #schema, assume all schemas except the default non-public ones (jeremyevans) (#305)
* Cache prepared statements when using the native sqlite driver, improving performance (jeremyevans)
View
@@ -350,7 +350,15 @@ def negative_boolean_constant_sql(constant)
# SQL fragment for the ordered expression, used in the ORDER BY
# clause.
def ordered_expression_sql(oe)
- "#{literal(oe.expression)} #{oe.descending ? 'DESC' : 'ASC'}"
+ s = "#{literal(oe.expression)} #{oe.descending ? 'DESC' : 'ASC'}"
+ case oe.opts[:nulls]
+ when :first
+ "#{s} NULLS FIRST"
+ when :last
+ "#{s} NULLS LAST"
+ else
+ s
+ end
end
# SQL fragment for a literal string with placeholders
View
@@ -368,13 +368,13 @@ module NumericMethods
# or more complex expressions.
module OrderMethods
# Mark the receiving SQL column as sorting in a descending fashion.
- def desc
- OrderedExpression.new(self)
+ def desc(opts={})
+ OrderedExpression.new(self, true, opts)
end
# Mark the receiving SQL column as sorting in an ascending fashion (generally a no-op).
- def asc
- OrderedExpression.new(self, false)
+ def asc(opts={})
+ OrderedExpression.new(self, false, opts)
end
end
@@ -754,30 +754,44 @@ class NumericExpression < ComplexExpression
# Represents a column/expression to order the result set by.
class OrderedExpression < Expression
+ INVERT_NULLS = {:first=>:last, :last=>:first}.freeze
+
# The expression to order the result set by.
attr_reader :expression
# Whether the expression should order the result set in a descending manner
attr_reader :descending
+ # Other options supported, such as :nulls
+ attr_reader :opts
+
# Set the expression and descending attributes to the given values.
- def initialize(expression, descending = true)
- @expression, @descending = expression, descending
+ def initialize(expression, descending = true, opts={})
+ @expression, @descending, @opts = expression, descending, opts
end
# Return a copy that is ASC
def asc
- OrderedExpression.new(@expression, false)
+ OrderedExpression.new(@expression, false, @opts)
end
# Return a copy that is DESC
def desc
- OrderedExpression.new(@expression)
+ OrderedExpression.new(@expression, true, @opts)
+ end
+
+ # Make sure that the hash value is the same if the attributes are the same.
+ def hash
+ [self.class, expression, descending, opts[:nulls]].hash
end
# Return an inverted expression, changing ASC to DESC and vice versa
def invert
- OrderedExpression.new(@expression, !@descending)
+ opts = @opts
+ if nul_dir = @opts[:nulls]
+ opts = opts.merge(:nulls=>INVERT_NULLS.fetch(nul_dir, nul_dir))
+ end
+ OrderedExpression.new(@expression, !@descending, opts)
end
to_s_method :ordered_expression_sql
@@ -130,6 +130,15 @@ def logger.method_missing(m, msg)
@d.filter(:name => /^bc/).count.should == 1
end
+ specify "should support NULLS FIRST and NULLS LAST" do
+ @d << {:name => 'abc'}
+ @d << {:name => 'bcd'}
+ @d << {:name => 'bcd', :value => 2}
+ @d.order(:value.asc(:nulls=>:first), :name).select_map(:name).should == %w[abc bcd bcd]
+ @d.order(:value.asc(:nulls=>:last), :name).select_map(:name).should == %w[bcd abc bcd]
+ @d.order(:value.asc(:nulls=>:first), :name).reverse.select_map(:name).should == %w[bcd bcd abc]
+ end
+
specify "#lock should lock tables and yield if a block is given" do
@d.lock('EXCLUSIVE'){@d.insert(:name=>'a')}
end
View
@@ -1204,6 +1204,11 @@ def d.to_s; "adsf" end
'SELECT * FROM test ORDER BY name, price DESC'
end
+ specify "should accept :nulls options for asc and desc" do
+ @dataset.order(:name.asc(:nulls=>:last), :price.desc(:nulls=>:first)).sql.should ==
+ 'SELECT * FROM test ORDER BY name ASC NULLS LAST, price DESC NULLS FIRST'
+ end
+
specify "should overrun a previous ordering" do
@dataset.order(:name).order(:stamp).sql.should ==
'SELECT * FROM test ORDER BY stamp'
@@ -1385,6 +1390,11 @@ def d.to_s; "adsf" end
'SELECT * FROM test ORDER BY name DESC, price ASC'
end
+ specify "should handles NULLS ordering correctly when reversing" do
+ @dataset.reverse_order(:name.asc(:nulls=>:first), :price.desc(:nulls=>:last)).sql.should ==
+ 'SELECT * FROM test ORDER BY name DESC NULLS LAST, price ASC NULLS FIRST'
+ end
+
specify "should reverse a previous ordering if no arguments are given" do
@dataset.order(:name).reverse_order.sql.should ==
'SELECT * FROM test ORDER BY name DESC'

0 comments on commit b938370

Please sign in to comment.