Skip to content

Commit

Permalink
add dt_SQL_subtract to DateMethods1
Browse files Browse the repository at this point in the history
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
  • Loading branch information
domm committed Jul 22, 2019
1 parent ba9ab1b commit de38468
Show file tree
Hide file tree
Showing 6 changed files with 310 additions and 4 deletions.
109 changes: 108 additions & 1 deletion lib/DBIx/Class/Helper/ResultSet/DateMethods1.pm
Original file line number Diff line number Diff line change
Expand Up @@ -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: {
Expand Down Expand Up @@ -122,7 +136,6 @@ sub _introspector {
}
});


my %diff_part_map = (
day => 'days',
hour => 'hours',
Expand All @@ -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: {
Expand Down Expand Up @@ -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: {
Expand Down Expand Up @@ -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: {
Expand Down Expand Up @@ -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;
}
Expand Down Expand Up @@ -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) = @_;

Expand Down Expand Up @@ -550,6 +646,17 @@ Takes three arguments: a date conforming to L</TYPES>, a unit, and an amount.
The idea is to add the given unit to the datetime. See your L</IMPLEMENTATION>
for what units are accepted.
=method dt_SQL_subtract
Same as L<dt_SQL_add>, 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<Thomas Klausner|https://domm.plix.at> and
sponsored by L<Ctrl O|https://www.ctrlo.com/>.
=method dt_SQL_pluck
# get count per year
Expand Down
7 changes: 6 additions & 1 deletion maint/explain-out
Original file line number Diff line number Diff line change
Expand Up @@ -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: $@";
}
}
21 changes: 21 additions & 0 deletions t/ResultSet/DateMethods1/mysql.t
Original file line number Diff line number Diff line change
Expand Up @@ -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;
24 changes: 24 additions & 0 deletions t/ResultSet/DateMethods1/pg.t
Original file line number Diff line number Diff line change
Expand Up @@ -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 => {
Expand Down
11 changes: 11 additions & 0 deletions t/ResultSet/DateMethods1/sqlite.t
Original file line number Diff line number Diff line change
Expand Up @@ -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<STRFTIME('%S', "me"."a_date")> ],

pluck_sql_by_part => {
Expand Down
Loading

0 comments on commit de38468

Please sign in to comment.