Permalink
Browse files

Add date_arithmetic extension for database-independent date calculations

This is supported on all 11 database types that Sequel is
regularly tested against.

While here, fix an minor issue in the postgres adapter specs when
activesupport is not installed.
  • Loading branch information...
1 parent bf31d5e commit 0172eccd59337b5668a781331ae284b3616359fb @jeremyevans committed Dec 14, 2012
View
@@ -1,5 +1,7 @@
=== HEAD
+* Add date_arithmetic extension for database-independent date calculations (jeremyevans)
+
* Make Database#schema handle [host.]database.schema.table qualified tables on Microsoft SQL Server (jeremyevans)
* Add Dataset#split_qualifiers helper method for splitting a qualifier identifier into array of strings (jeremyevans)
@@ -0,0 +1,194 @@
+# The date_arithmetic extension adds the ability to perform database-independent
+# addition/substraction of intervals to/from dates and timestamps.
+#
+# First, you need to load the extension into the database:
+#
+# DB.extension :date_arithmetic
+#
+# Then you can use the Sequel.date_add and Sequel.date_sub methods
+# to return Sequel expressions:
+#
+# add = Sequel.date_add(:date_column, :years=>1, :months=>2, :days=>3)
+# sub = Sequel.date_sub(:date_column, :hours=>1, :minutes=>2, :seconds=>3)
+#
+# In addition to specifying the interval as a hash, there is also
+# support for specifying the interval as an ActiveSupport::Duration
+# object:
+#
+# require 'active_support/all'
+# add = Sequel.date_add(:date_column, 1.years + 2.months + 3.days)
+# sub = Sequel.date_sub(:date_column, 1.hours + 2.minutes + 3.seconds)
+#
+# These expressions can be used in your datasets, or anywhere else that
+# Sequel expressions are allowed:
+#
+# DB[:table].select(add.as(:d)).where(sub > Sequel::CURRENT_TIMESTAMP)
+
+module Sequel
+ module SQL
+ module Builders
+ # Return a DateAdd expression, adding an interval to the date/timestamp expr.
+ def date_add(expr, interval)
+ DateAdd.new(expr, interval)
+ end
+
+ # Return a DateAdd expression, adding the negative of the interval to
+ # the date/timestamp expr.
+ def date_sub(expr, interval)
+ interval = if interval.is_a?(Hash)
+ h = {}
+ interval.each{|k,v| h[k] = -v unless v.nil?}
+ h
+ else
+ -interval
+ end
+ DateAdd.new(expr, interval)
+ end
+ end
+
+ # The DateAdd class represents the addition of an interval to a
+ # date/timestamp expression.
+ class DateAdd < GenericExpression
+ # These methods are added to datasets using the date_arithmetic
+ # extension, for the purposes of correctly literalizing DateAdd
+ # expressions for the appropriate database type.
+ module DatasetMethods
+ DURATION_UNITS = [:years, :months, :days, :hours, :minutes, :seconds].freeze
+ DEF_DURATION_UNITS = DURATION_UNITS.zip(DURATION_UNITS.map{|s| s.to_s.freeze}).freeze
+ MYSQL_DURATION_UNITS = DURATION_UNITS.zip(DURATION_UNITS.map{|s| Sequel.lit(s.to_s.upcase[0...-1]).freeze}).freeze
+ MSSQL_DURATION_UNITS = DURATION_UNITS.zip(DURATION_UNITS.map{|s| Sequel.lit(s.to_s[0...-1]).freeze}).freeze
+ H2_DURATION_UNITS = DURATION_UNITS.zip(DURATION_UNITS.map{|s| s.to_s[0...-1].freeze}).freeze
+ DERBY_DURATION_UNITS = DURATION_UNITS.zip(DURATION_UNITS.map{|s| Sequel.lit("SQL_TSI_#{s.to_s.upcase[0...-1]}").freeze}).freeze
+ ACCESS_DURATION_UNITS = DURATION_UNITS.zip(%w'yyyy m d h n s'.map{|s| s.freeze}).freeze
+ DB2_DURATION_UNITS = DURATION_UNITS.zip(DURATION_UNITS.map{|s| Sequel.lit(s.to_s).freeze}).freeze
+
+ # Return an SQL fragment for the literalized version of the
+ # DateAdd expression.
+ def date_add_sql(da)
+ sql = ''
+ date_arith_sql_append(sql, da)
+ sql
+ end
+
+ # Append the SQL fragment for the DateAdd expression to the SQL query.
+ def date_add_sql_append(sql, da)
+ h = da.interval
+ expr = da.expr
+ cast = case db_type = db.database_type
+ when :postgres
+ interval = ""
+ each_valid_interval_unit(h, DEF_DURATION_UNITS) do |value, sql_unit|
+ interval << "#{value} #{sql_unit} "
+ end
+ if interval.empty?
+ return literal_append(sql, Sequel.cast(expr, Time))
+ else
+ return complex_expression_sql_append(sql, :+, [Sequel.cast(expr, Time), Sequel.cast(interval, :interval)])
+ end
+ when :sqlite
+ args = [expr]
+ each_valid_interval_unit(h, DEF_DURATION_UNITS) do |value, sql_unit|
+ args << "#{value} #{sql_unit}"
+ end
+ return _function_sql_append(sql, :datetime, args)
+ when :mysql, :hsqldb, :cubrid
+ if db_type == :hsqldb
+ # HSQLDB requires 2.2.9+ for the DATE_ADD function
+ expr = Sequel.cast(expr, Time)
+ end
+ each_valid_interval_unit(h, MYSQL_DURATION_UNITS) do |value, sql_unit|
+ expr = Sequel.function(:DATE_ADD, expr, Sequel.lit(["INTERVAL ", " "], value, sql_unit))
+ end
+ when :mssql, :h2, :access
+ units = case db_type
+ when :mssql
+ MSSQL_DURATION_UNITS
+ when :h2
+ H2_DURATION_UNITS
+ when :access
+ ACCESS_DURATION_UNITS
+ end
+ each_valid_interval_unit(h, units) do |value, sql_unit|
+ expr = Sequel.function(:DATEADD, sql_unit, value, expr)
+ end
+ when :derby
+ if expr.is_a?(Date) && !expr.is_a?(DateTime)
+ # Work around for https://issues.apache.org/jira/browse/DERBY-896
+ expr = Sequel.cast_string(expr) + ' 00:00:00'
+ end
+ each_valid_interval_unit(h, DERBY_DURATION_UNITS) do |value, sql_unit|
+ expr = Sequel.lit(["{fn timestampadd(#{sql_unit}, ", ", timestamp(", "))}"], value, expr)
+ end
+ when :oracle
+ each_valid_interval_unit(h, MYSQL_DURATION_UNITS) do |value, sql_unit|
+ expr = Sequel.+(expr, Sequel.lit(["INTERVAL ", " "], value.to_s, sql_unit))
+ end
+ when :db2
+ expr = Sequel.cast(expr, Time)
+ each_valid_interval_unit(h, DB2_DURATION_UNITS) do |value, sql_unit|
+ expr = Sequel.+(expr, Sequel.lit(["", " "], value, sql_unit))
+ end
+ false
+ else
+ raise NotImplemented, "date arithmetic is not implemented on #{db.database_type}"
+ end
+
+ if cast
+ expr = Sequel.cast(expr, Time)
+ end
+
+ literal_append(sql, expr)
+ end
+
+ private
+
+ # Yield the value in the interval for each of the units
+ # present in the interval, along with the SQL fragment
+ # representing the unit name. Returns false if any
+ # values were yielded, true otherwise
+ def each_valid_interval_unit(interval, units)
+ cast = true
+ units.each do |unit, sql_unit|
+ if (value = interval[unit]) && value != 0
+ cast = false
+ yield value, sql_unit
+ end
+ end
+ cast
+ end
+ end
+
+ # The expression that the interval is being added to.
+ attr_reader :expr
+
+ # The interval added to the expression, as a hash with
+ # symbol keys.
+ attr_reader :interval
+
+ # Supports two types of intervals:
+ # Hash :: Used directly, but values cannot be plain strings.
+ # ActiveSupport::Duration :: Converted to a hash using the interval's parts.
+ def initialize(expr, interval)
+ @expr = expr
+ @interval = if interval.is_a?(Hash)
+ interval.each_value do |v|
+ # Attempt to prevent SQL injection by users who pass untrusted strings
+ # as interval values.
+ if v.is_a?(String) && !v.is_a?(LiteralString)
+ raise Sequel::InvalidValue, "cannot provide String value as interval part: #{v.inspect}"
+ end
+ end
+ interval
+ else
+ h = Hash.new(0)
+ interval.parts.each{|unit, value| h[unit] += value}
+ {}.merge(h)
+ end
+ end
+
+ to_s_method :date_add_sql
+ end
+ end
+
+ Dataset.register_extension(:date_arithmetic, SQL::DateAdd::DatasetMethods)
+end
@@ -2524,7 +2524,7 @@ def left_item_id
v.should == ActiveSupport::Duration.new(31557600 + 2*86400*30 + 3*86400*7 + 4*86400 + 5*3600 + 6*60 + 7, [[:years, 1], [:months, 2], [:days, 25], [:seconds, 18367]])
v.parts.sort_by{|k,v| k.to_s}.should == [[:years, 1], [:months, 2], [:days, 25], [:seconds, 18367]].sort_by{|k,v| k.to_s}
end
-end if ((require 'active_support/duration'; require 'active_support/inflector'; require 'active_support/core_ext/string/inflections'; true) rescue false)
+end if (begin require 'active_support/duration'; require 'active_support/inflector'; require 'active_support/core_ext/string/inflections'; true; rescue LoadError; false end)
describe 'PostgreSQL row-valued/composite types' do
before(:all) do
@@ -0,0 +1,150 @@
+require File.join(File.dirname(File.expand_path(__FILE__)), "spec_helper")
+
+asd = begin
+ require 'active_support/duration'
+ true
+rescue LoadError => e
+ skip_warn "date_arithmetic extension (partial): can't load active_support/duration (#{e.class}: #{e})"
+ false
+end
+
+Sequel.extension :date_arithmetic
+
+describe "date_arithmetic extension" do
+ dbf = lambda do |db_type|
+ db = Sequel.connect("mock://#{db_type}")
+ db.extension :date_arithmetic
+ db
+ end
+
+ before do
+ @h0 = {:days=>0}
+ @h1 = {:days=>1, :years=>nil, :hours=>0}
+ @h2 = {:years=>1, :months=>1, :days=>1, :hours=>1, :minutes=>1, :seconds=>1}
+ end
+
+ it "should have Sequel.date_add with an interval hash return an appropriate Sequel::SQL::DateAdd expression" do
+ da = Sequel.date_add(:a, :days=>1)
+ da.should be_a_kind_of(Sequel::SQL::DateAdd)
+ da.expr.should == :a
+ da.interval.should == {:days=>1}
+ Sequel.date_add(:a, :years=>1, :months=>2, :days=>3, :hours=>1, :minutes=>1, :seconds=>1).interval.should == {:years=>1, :months=>2, :days=>3, :hours=>1, :minutes=>1, :seconds=>1}
+ end
+
+ it "should have Sequel.date_sub with an interval hash return an appropriate Sequel::SQL::DateAdd expression" do
+ da = Sequel.date_sub(:a, :days=>1)
+ da.should be_a_kind_of(Sequel::SQL::DateAdd)
+ da.expr.should == :a
+ da.interval.should == {:days=>-1}
+ Sequel.date_sub(:a, :years=>1, :months=>2, :days=>3, :hours=>1, :minutes=>1, :seconds=>1).interval.should == {:years=>-1, :months=>-2, :days=>-3, :hours=>-1, :minutes=>-1, :seconds=>-1}
+ end
+
+ it "should have Sequel.date_* with an interval hash handle nil values" do
+ Sequel.date_sub(:a, :days=>1, :hours=>nil).interval.should == {:days=>-1}
+ end
+
+ it "should raise an error if given string values in an interval hash" do
+ lambda{Sequel.date_add(:a, :days=>'1')}.should raise_error(Sequel::InvalidValue)
+ end
+
+ if asd
+ it "should have Sequel.date_add with an ActiveSupport::Duration return an appropriate Sequel::SQL::DateAdd expression" do
+ da = Sequel.date_add(:a, ActiveSupport::Duration.new(1, [[:days, 1]]))
+ da.should be_a_kind_of(Sequel::SQL::DateAdd)
+ da.expr.should == :a
+ da.interval.should == {:days=>1}
+ Sequel.date_add(:a, ActiveSupport::Duration.new(1, [[:years, 1], [:months, 1], [:days, 1], [:minutes, 61], [:seconds, 1]])).interval.should == {:years=>1, :months=>1, :days=>1, :minutes=>61, :seconds=>1}
+ end
+
+ it "should have Sequel.date_sub with an ActiveSupport::Duration return an appropriate Sequel::SQL::DateAdd expression" do
+ da = Sequel.date_sub(:a, ActiveSupport::Duration.new(1, [[:days, 1]]))
+ da.should be_a_kind_of(Sequel::SQL::DateAdd)
+ da.expr.should == :a
+ da.interval.should == {:days=>-1}
+ Sequel.date_sub(:a, ActiveSupport::Duration.new(1, [[:years, 1], [:months, 1], [:days, 1], [:minutes, 61], [:seconds, 1]])).interval.should == {:years=>-1, :months=>-1, :days=>-1, :minutes=>-61, :seconds=>-1}
+ end
+ end
+
+ it "should correctly literalize on Postgres" do
+ db = dbf.call(:postgres)
+ db.literal(Sequel.date_add(:a, @h0)).should == "CAST(a AS timestamp)"
+ db.literal(Sequel.date_add(:a, @h1)).should == "(CAST(a AS timestamp) + CAST('1 days ' AS interval))"
+ db.literal(Sequel.date_add(:a, @h2)).should == "(CAST(a AS timestamp) + CAST('1 years 1 months 1 days 1 hours 1 minutes 1 seconds ' AS interval))"
+ end
+
+ it "should correctly literalize on SQLite" do
+ db = dbf.call(:sqlite)
+ db.literal(Sequel.date_add(:a, @h0)).should == "datetime(a)"
+ db.literal(Sequel.date_add(:a, @h1)).should == "datetime(a, '1 days')"
+ db.literal(Sequel.date_add(:a, @h2)).should == "datetime(a, '1 years', '1 months', '1 days', '1 hours', '1 minutes', '1 seconds')"
+ end
+
+ it "should correctly literalize on MySQL" do
+ db = dbf.call(:mysql)
+ db.literal(Sequel.date_add(:a, @h0)).should == "CAST(a AS DATETIME)"
+ db.literal(Sequel.date_add(:a, @h1)).should == "DATE_ADD(a, INTERVAL 1 DAY)"
+ db.literal(Sequel.date_add(:a, @h2)).should == "DATE_ADD(DATE_ADD(DATE_ADD(DATE_ADD(DATE_ADD(DATE_ADD(a, INTERVAL 1 YEAR), INTERVAL 1 MONTH), INTERVAL 1 DAY), INTERVAL 1 HOUR), INTERVAL 1 MINUTE), INTERVAL 1 SECOND)"
+ end
+
+ it "should correctly literalize on HSQLDB" do
+ db = Sequel.mock
+ def db.database_type; :hsqldb end
+ db.extension :date_arithmetic
+ db.literal(Sequel.date_add(:a, @h0)).should == "CAST(CAST(a AS timestamp) AS timestamp)"
+ db.literal(Sequel.date_add(:a, @h1)).should == "DATE_ADD(CAST(a AS timestamp), INTERVAL 1 DAY)"
+ db.literal(Sequel.date_add(:a, @h2)).should == "DATE_ADD(DATE_ADD(DATE_ADD(DATE_ADD(DATE_ADD(DATE_ADD(CAST(a AS timestamp), INTERVAL 1 YEAR), INTERVAL 1 MONTH), INTERVAL 1 DAY), INTERVAL 1 HOUR), INTERVAL 1 MINUTE), INTERVAL 1 SECOND)"
+ end
+
+ it "should correctly literalize on MSSQL" do
+ db = dbf.call(:mssql)
+ db.literal(Sequel.date_add(:a, @h0)).should == "CAST(a AS datetime)"
+ db.literal(Sequel.date_add(:a, @h1)).should == "DATEADD(day, 1, a)"
+ db.literal(Sequel.date_add(:a, @h2)).should == "DATEADD(second, 1, DATEADD(minute, 1, DATEADD(hour, 1, DATEADD(day, 1, DATEADD(month, 1, DATEADD(year, 1, a))))))"
+ end
+
+ it "should correctly literalize on H2" do
+ db = Sequel.mock
+ def db.database_type; :h2 end
+ db.extension :date_arithmetic
+ db.literal(Sequel.date_add(:a, @h0)).should == "CAST(a AS timestamp)"
+ db.literal(Sequel.date_add(:a, @h1)).should == "DATEADD('day', 1, a)"
+ db.literal(Sequel.date_add(:a, @h2)).should == "DATEADD('second', 1, DATEADD('minute', 1, DATEADD('hour', 1, DATEADD('day', 1, DATEADD('month', 1, DATEADD('year', 1, a))))))"
+ end
+
+ it "should correctly literalize on access" do
+ db = dbf.call(:access)
+ db.literal(Sequel.date_add(:a, @h0)).should == "CDate(a)"
+ db.literal(Sequel.date_add(:a, @h1)).should == "DATEADD('d', 1, a)"
+ db.literal(Sequel.date_add(:a, @h2)).should == "DATEADD('s', 1, DATEADD('n', 1, DATEADD('h', 1, DATEADD('d', 1, DATEADD('m', 1, DATEADD('yyyy', 1, a))))))"
+ end
+
+ it "should correctly literalize on Derby" do
+ db = Sequel.mock
+ def db.database_type; :derby end
+ db.extension :date_arithmetic
+ db.literal(Sequel.date_add(:a, @h0)).should == "CAST(a AS timestamp)"
+ db.literal(Sequel.date_add(:a, @h1)).should == "{fn timestampadd(SQL_TSI_DAY, 1, timestamp(a))}"
+ db.literal(Sequel.date_add(:a, @h2)).should == "{fn timestampadd(SQL_TSI_SECOND, 1, timestamp({fn timestampadd(SQL_TSI_MINUTE, 1, timestamp({fn timestampadd(SQL_TSI_HOUR, 1, timestamp({fn timestampadd(SQL_TSI_DAY, 1, timestamp({fn timestampadd(SQL_TSI_MONTH, 1, timestamp({fn timestampadd(SQL_TSI_YEAR, 1, timestamp(a))}))}))}))}))}))}"
+ db.literal(Sequel.date_add(Date.civil(2012, 11, 12), @h1)).should == "{fn timestampadd(SQL_TSI_DAY, 1, timestamp((CAST('2012-11-12' AS varchar(255)) || ' 00:00:00')))}"
+ end
+
+ it "should correctly literalize on Oracle" do
+ db = dbf.call(:oracle)
+ db.literal(Sequel.date_add(:a, @h0)).should == "CAST(a AS timestamp)"
+ db.literal(Sequel.date_add(:a, @h1)).should == "(a + INTERVAL '1' DAY)"
+ db.literal(Sequel.date_add(:a, @h2)).should == "(a + INTERVAL '1' YEAR + INTERVAL '1' MONTH + INTERVAL '1' DAY + INTERVAL '1' HOUR + INTERVAL '1' MINUTE + INTERVAL '1' SECOND)"
+ end
+
+ it "should correctly literalize on DB2" do
+ db = dbf.call(:db2)
+ db.literal(Sequel.date_add(:a, @h0)).should == "CAST(a AS timestamp)"
+ db.literal(Sequel.date_add(:a, @h1)).should == "(CAST(a AS timestamp) + 1 days)"
+ db.literal(Sequel.date_add(:a, @h2)).should == "(CAST(a AS timestamp) + 1 years + 1 months + 1 days + 1 hours + 1 minutes + 1 seconds)"
+ end
+
+ it "should raise error if literalizing on an unsupported database" do
+ db = Sequel.mock
+ db.extension :date_arithmetic
+ lambda{db.literal(Sequel.date_add(:a, @h0))}.should raise_error(Sequel::NotImplemented)
+ end
+end
Oops, something went wrong.

0 comments on commit 0172ecc

Please sign in to comment.