From de384685465bcbea2b10ddca5fcb0d0693001ff7 Mon Sep 17 00:00:00 2001 From: Thomas Klausner Date: Wed, 10 Jul 2019 21:21:09 +0200 Subject: [PATCH] add dt_SQL_subtract to DateMethods1 This commit adds the new method dt_SQL_subtract to DBIx::Class::Helper::ResultSet::DateMethods1 It works exactly like dt_SQL_add, but subtracts dates (surprise!). While one can pass negative values to dt_SQL_add to subtract a literal value ($amount), this does not work when the value is not passed as a literal value but as the name of another column where the actual value is stored. Hence this new method. - dt_SQL_subtract tests for Postgres, MySQL and SQLite - add sponsor note --- .../Class/Helper/ResultSet/DateMethods1.pm | 109 +++++++++++++- maint/explain-out | 7 +- t/ResultSet/DateMethods1/mysql.t | 21 +++ t/ResultSet/DateMethods1/pg.t | 24 +++ t/ResultSet/DateMethods1/sqlite.t | 11 ++ t/lib/A/ResultSet/DateMethods1.pm | 142 +++++++++++++++++- 6 files changed, 310 insertions(+), 4 deletions(-) diff --git a/lib/DBIx/Class/Helper/ResultSet/DateMethods1.pm b/lib/DBIx/Class/Helper/ResultSet/DateMethods1.pm index 196fe89..bd00c64 100644 --- a/lib/DBIx/Class/Helper/ResultSet/DateMethods1.pm +++ b/lib/DBIx/Class/Helper/ResultSet/DateMethods1.pm @@ -90,6 +90,20 @@ sub _introspector { ]; } }); + + $d->decorate_driver_unconnected(MSSQL => datesubtract_sql => sub { + sub { + my ($date_sql, $unit, $amount_sql) = @_; + + my ($d_sql, @d_args) = @{$date_sql}; + my ($a_sql, @a_args) = @{$amount_sql}; + + return [ # no idea if this works.. + "DATEADD($diff_part_map{$unit}, -1 * CAST($a_sql AS int), $d_sql)", + @a_args, @d_args, + ]; + } + }); } SQLITE: { @@ -122,7 +136,6 @@ sub _introspector { } }); - my %diff_part_map = ( day => 'days', hour => 'hours', @@ -147,6 +160,22 @@ sub _introspector { ]; } }); + + $d->decorate_driver_unconnected(SQLite => datesubtract_sql => sub { + sub { + my ($date_sql, $unit, $amount_sql) = @_; + + my ($d_sql, @d_args) = @{$date_sql}; + my ($a_sql, @a_args) = @{$amount_sql}; + + die "unknown part $unit" unless $diff_part_map{$unit}; + + return [ + "DATETIME($d_sql, '-' || $a_sql || ?)", + @d_args, @a_args, " $diff_part_map{$unit}" + ]; + } + }); } PG: { @@ -214,6 +243,25 @@ sub _introspector { ]; } }); + + $d->decorate_driver_unconnected(Pg => datesubtract_sql => sub { + sub { + my ($date_sql, $unit, $amount_sql) = @_; + + my ($d_sql, @d_args) = @{$date_sql}; + my ($a_sql, @a_args) = @{$amount_sql}; + + @d_args = ([{ dbd_attrs => SQL_TIMESTAMP }, $d_args[0]]) + if $d_sql eq '?' && @d_args == 1; + + die "unknown part $unit" unless $diff_part_map{$unit}; + + return [ + "($d_sql - $a_sql * interval '1 $diff_part_map{$unit}')", + @d_args, @a_args, + ]; + } + }); } MYSQL: { @@ -275,6 +323,22 @@ sub _introspector { ]; } }); + + $d->decorate_driver_unconnected(mysql => datesubtract_sql => sub { + sub { + my ($date_sql, $unit, $amount_sql) = @_; + + my ($d_sql, @d_args) = @{$date_sql}; + my ($a_sql, @a_args) = @{$amount_sql}; + + die "unknown part $unit" unless $diff_part_map{$unit}; + + return [ + "DATE_SUB($d_sql, INTERVAL $a_sql $diff_part_map{$unit})", + @d_args, @a_args, + ]; + } + }); } ORACLE: { @@ -317,6 +381,21 @@ sub _introspector { ]; } }); + $d->decorate_driver_unconnected(Oracle => datesubtract_sql => sub { + sub { + my ($date_sql, $unit, $amount_sql) = @_; + + my ($d_sql, @d_args) = @{$date_sql}; + my ($a_sql, @a_args) = @{$amount_sql}; + + die "unknown unit $unit" unless $diff_part_map{$unit}; + + return [ # no idea if this works.. + "(TO_TIMESTAMP($d_sql) - NUMTODSINTERVAL($a_sql, ?))", + @d_args, @a_args, $diff_part_map{$unit} + ]; + } + }); } return $d; } @@ -428,6 +507,23 @@ sub dt_SQL_add { ); } +sub dt_SQL_subtract { + my ($self, $thing, $unit, $amount) = @_; + + my $storage = $self->result_source->storage; + $storage->ensure_connected; + + $d ||= _introspector(); + + return \( + $d->get($storage->dbh, undef, 'datesubtract_sql')->( + [ _flatten_thing($self, $thing) ], + $unit, + [ _flatten_thing($self, $amount) ], + ) + ); +} + sub dt_SQL_pluck { my ($self, $thing, $part) = @_; @@ -550,6 +646,17 @@ Takes three arguments: a date conforming to L, a unit, and an amount. The idea is to add the given unit to the datetime. See your L for what units are accepted. +=method dt_SQL_subtract + +Same as L, but subtracts the amount. + +Only confirmed to work with Postgres, MySQL and SQLite. It should work with Oracle +and MSSQL, but due to lack of access to those DB engines the implementation was +done only based on docs. + +This method was implemented by L and +sponsored by L. + =method dt_SQL_pluck # get count per year diff --git a/maint/explain-out b/maint/explain-out index 28bf3f4..c7b8dbc 100755 --- a/maint/explain-out +++ b/maint/explain-out @@ -15,5 +15,10 @@ if ($engine eq 'SQLite') { $s->deploy; print Dumper($s->resultset('Gnarly')->explain) } else { - print Dumper(A::Util::connect($engine, $engine)->resultset('Gnarly')->explain) + eval { + print Dumper(A::Util::connect($engine, $engine)->resultset('Gnarly')->explain) + }; + if ($@) { + print "Problem during maint/explain-out, but probably not fatal: $@"; + } } diff --git a/t/ResultSet/DateMethods1/mysql.t b/t/ResultSet/DateMethods1/mysql.t index fc4a70e..c21b1ab 100644 --- a/t/ResultSet/DateMethods1/mysql.t +++ b/t/ResultSet/DateMethods1/mysql.t @@ -73,6 +73,27 @@ A::ResultSet::DateMethods1->run_tests(mysql => { quarter => '2014-12-12 00:00:00', week => '2013-02-13 00:00:00', }, + + subtract_sql_prefix => \[ 'DATE_SUB(`me`.`a_date`, INTERVAL ? SECOND)', 1 ], + + subtract_sql_by_part => { + day => \[ 'DATE_SUB(`a_date`, INTERVAL ? DAY)', 1 ], + hour => \[ 'DATE_SUB(`a_date`, INTERVAL ? HOUR)', 2 ], + microsecond => \[ 'DATE_SUB(`a_date`, INTERVAL ? MICROSECOND)', 7 ], + minute => \[ 'DATE_SUB(`a_date`, INTERVAL ? MINUTE)', 3 ], + month => \[ 'DATE_SUB(`a_date`, INTERVAL ? MONTH)', 4 ], + quarter => \[ 'DATE_SUB(`a_date`, INTERVAL ? QUARTER)', 8 ], + second => \[ 'DATE_SUB(`a_date`, INTERVAL ? SECOND)', 5 ], + week => \[ 'DATE_SUB(`a_date`, INTERVAL ? WEEK)', 9 ], + year => \[ 'DATE_SUB(`a_date`, INTERVAL ? YEAR)', 6 ], + }, + + subtract_sql_by_part_result => { + microsecond => '2012-12-11 23:59:59.999993', + second => qr/^2012-12-11 23:59:55/, + quarter => '2010-12-12 00:00:00', + week => '2012-10-10 00:00:00', + }, }); done_testing; diff --git a/t/ResultSet/DateMethods1/pg.t b/t/ResultSet/DateMethods1/pg.t index f44a384..be43506 100644 --- a/t/ResultSet/DateMethods1/pg.t +++ b/t/ResultSet/DateMethods1/pg.t @@ -37,6 +37,30 @@ A::ResultSet::DateMethods1->run_tests(Pg => { week => '2013-02-27 00:00:00', }, + subtract_sql_prefix => \[ q<("me"."a_date" - ? * interval '1 second')>, 1], + + subtract_sql_by_part => { + century => \[ q<("a_date" - ? * interval '1 century')>, 7 ], + day => \[ q<("a_date" - ? * interval '1 day')>, 1 ], + decade => \[ q<("a_date" - ? * interval '1 decade')>, 8 ], + hour => \[ q<("a_date" - ? * interval '1 hour')>, 2 ], + microsecond => \[ q<("a_date" - ? * interval '1 microseconds')>, 9 ], + millisecond => \[ q<("a_date" - ? * interval '1 milliseconds')>, 10 ], + minute => \[ q<("a_date" - ? * interval '1 minute')>, 3 ], + month => \[ q<("a_date" - ? * interval '1 month')>, 4 ], + second => \[ q<("a_date" - ? * interval '1 second')>, 5 ], + week => \[ q<("a_date" - ? * interval '1 week')>, 11 ], + year => \[ q<("a_date" - ? * interval '1 year')>, 6 ], + }, + + subtract_sql_by_part_result => { + century => '1312-12-12 00:00:00', + decade => '1932-12-12 00:00:00', + microsecond => '2012-12-11 23:59:59.999991', + millisecond => '2012-12-11 23:59:59.99', + week => '2012-09-26 00:00:00', + }, + pluck_sql_prefix => \[ 'date_part(?, "me"."a_date")', 'second' ], pluck_sql_by_part => { diff --git a/t/ResultSet/DateMethods1/sqlite.t b/t/ResultSet/DateMethods1/sqlite.t index feca2f4..989646f 100644 --- a/t/ResultSet/DateMethods1/sqlite.t +++ b/t/ResultSet/DateMethods1/sqlite.t @@ -28,6 +28,17 @@ A::ResultSet::DateMethods1->run_tests(SQLite => { year => \[ 'DATETIME("a_date", ? || ?)', 6, ' years' ], }, + subtract_sql_prefix => \[ q{DATETIME("me"."a_date", '-' || ? || ?)}, 1, ' seconds' ], + + subtract_sql_by_part => { + day => \[ q{DATETIME("a_date", '-' || ? || ?)}, 1, ' days' ], + hour => \[ q{DATETIME("a_date", '-' || ? || ?)}, 2, ' hours' ], + minute => \[ q{DATETIME("a_date", '-' || ? || ?)}, 3, ' minutes' ], + month => \[ q{DATETIME("a_date", '-' || ? || ?)}, 4, ' months' ], + second => \[ q{DATETIME("a_date", '-' || ? || ?)}, 5, ' seconds' ], + year => \[ q{DATETIME("a_date", '-' || ? || ?)}, 6, ' years' ], + }, + pluck_sql_prefix => \[ q ], pluck_sql_by_part => { diff --git a/t/lib/A/ResultSet/DateMethods1.pm b/t/lib/A/ResultSet/DateMethods1.pm index dc0bc70..90efae9 100644 --- a/t/lib/A/ResultSet/DateMethods1.pm +++ b/t/lib/A/ResultSet/DateMethods1.pm @@ -18,13 +18,14 @@ sub _dt { has [qw( add_sql_by_part_skip add_sql_by_part_result + subtract_sql_by_part_skip subtract_sql_by_part_result pluck_sql_by_part_skip pluck_sql_by_part_result )] => ( is => 'ro', default => sub { {} }, ); -has [map "${_}_sql_by_part", qw(pluck add)] => ( +has [map "${_}_sql_by_part", qw(pluck add subtract)] => ( is => 'ro', default => sub { {} }, ); @@ -37,7 +38,7 @@ sub skip_reason { } has [qw( - utc_now stringified_date add_sql_prefix sub_sql pluck_sql_prefix + utc_now stringified_date add_sql_prefix subtract_sql_prefix sub_sql pluck_sql_prefix )] => (is => 'ro'); has plucked_minute => ( @@ -88,6 +89,20 @@ sub _merged_add_sql_by_part_result { } } +sub _merged_subtract_sql_by_part_result { + my $self = shift; + + return +{ + day => '2012-12-11 00:00:00', + hour => '2012-12-11 22:00:00', + minute => '2012-12-11 23:57:00', + month => '2012-08-12 00:00:00', + second => '2012-12-11 23:59:55', + year => '2006-12-12 00:00:00', + %{$self->subtract_sql_by_part_result}, + } +} + sub rs { shift->schema->resultset('HasDateOps') } sub pop_rs_1 { @@ -381,6 +396,129 @@ test add => sub { } }; +test subtract => sub { + my $self = shift; + + $self->pop_rs_1 if $self->connected; + + SKIP: { + skip $self->engine . q(doesn't set subtract_sql_prefix) unless $self->subtract_sql_prefix; + + my %offset = ( + day => 1, + hour => 2, + minute => 3, + month => 4, + second => 5, + year => 6, + ); + my $i = 1 + scalar keys %offset; + for my $part (sort keys %{$self->subtract_sql_by_part}) { + my $query = $self->rs->dt_SQL_subtract( + { -ident => 'a_date' }, + $part, + $offset{$part} || $i++, + ); + + SKIP: { + skip $self->skip_reason, 1 unless $self->connected; + skip $self->subtract_sql_by_part_skip->{$part}, 1 + if $self->subtract_sql_by_part_skip->{$part}; + + my $v; + my $e = exception { + $v = $self->rs->search({ id => 1 }, { + columns => { v => $query }, + })->get_column('v')->next; + }; + ok !$e, "live $part" or diag "exception: $e"; + my $expected = $self->_merged_subtract_sql_by_part_result->{$part}; + + if (ref $expected && ref $expected eq 'Regexp') { + like($v, $expected, "suspected $part"); + } else { + is($v, $expected, "suspected $part"); + } + } + + cmp_deeply( + $query, + $self->subtract_sql_by_part->{$part}, + "unit: $part", + ); + } + + cmp_deeply( + $self->rs->dt_SQL_subtract({ -ident => '.a_date' }, 'second', 1), + $self->subtract_sql_prefix, + 'vanilla subtract', + ); + } + + SKIP: { + skip $self->skip_reason, 1 unless $self->connected; + + my $dt = DateTime->new( + time_zone => 'UTC', + year => 2013, + month => 12, + day => 11, + hour => 10, + minute => 9, + second => 8, + ); + + $self->rs->delete; + $self->rs->create({ id => 1, a_date => $self->rs->utc($dt) }); + + subtest column => sub { + my $subtracted = $self->rs->search(undef, { + rows => 1, + columns => { foo => + $self->rs->dt_SQL_subtract( + $self->rs->dt_SQL_subtract( + $self->rs->dt_SQL_subtract({ -ident => '.a_date' }, 'minute', 2), + second => 4, + ), hour => 1, + ), + }, + result_class => 'DBIx::Class::ResultClass::HashRefInflator', + })->first->{foo}; + $subtracted = $self->parse_datetime($subtracted); + + is($subtracted->year => 2013, 'subtracted year'); + is($subtracted->month => 12, 'subtracted month'); + is($subtracted->day => 11, 'subtracted day'); + is($subtracted->hour => 9, 'subtracted hour'); + is($subtracted->minute => 7, 'subtracted minute'); + is($subtracted->second => 4, 'subtracted second'); + }; + + subtest bindarg => sub { + my $subtracted = $self->rs->search(undef, { + rows => 1, + columns => { foo => + $self->rs->dt_SQL_subtract( + $self->rs->dt_SQL_subtract( + $self->rs->dt_SQL_subtract($dt, 'minute', 2), + second => 4, + ), hour => 1, + ), + }, + result_class => 'DBIx::Class::ResultClass::HashRefInflator', + })->first->{foo}; + $subtracted = $self->parse_datetime($subtracted); + + is($subtracted->year => 2013, 'subtracted year'); + is($subtracted->month => 12, 'subtracted month'); + is($subtracted->day => 11, 'subtracted day'); + is($subtracted->hour => 9, 'subtracted hour'); + is($subtracted->minute => 7, 'subtracted minute'); + is($subtracted->second => 4, 'subtracted second'); + }; + } +}; + test pluck => sub { my $self = shift;