Merge 'Add partial support for datetime() function' from Preston Thorpe

This PR adds the `datetime` function, with all the support currently
that date/time have for modifiers, and `julianday` function, as well as
some additional modifiers for date/time/datetime.
There are a couple considerations here, I left a couple comments but
essentially there is going to have to be some more work done to track
the state of the expression during the application of modifiers, to
handle a bunch of edge-cases like re-applying the same timezone modifier
to itself, or converting an integer automatically assumed to be
julianday, into epoch, or `ceiling`/`floor` which will determine
relative addition of time in cases like
```
2024-01-31 +1 month = 2024-03-02
```
which was painful enough to get working to begin with.
I couldn't get the `julianday_converter` library to get the exact same
float precision as sqlite, so function is included that matches their
output, for some reason floating point math + `.floor()` would give the
correct result. They seem to 'round' to 8 decimal places, and I was able
to get this to work with the same output as sqlite, except in cases like
`2234.5`, in which case we return `2234.5000000` because of the `fmt`
precision:
```rust
pub fn exec_julianday(time_value: &OwnedValue) -> Result<String> {
    let dt = parse_naive_date_time(time_value);
    match dt {
        // if we did something heinous like: parse::<f64>().unwrap().to_string()
        // that would solve the precision issue, but dear lord...
        Some(dt) => Ok(format!("{:.1$}", to_julian_day_exact(&dt), 8)),
        None => Ok(String::new()),
    }
}
```
Suggestions would be appreciated on the float precision issue.

Reviewed-by: Sonny <14060682+sonhmai@users.noreply.github.com>

Closes #600
This commit is contained in:
Pekka Enberg
2025-01-05 20:13:13 +02:00
6 changed files with 963 additions and 155 deletions

View File

@@ -233,4 +233,213 @@ do_execsql_test unixepoch-at-start-of-time {
do_execsql_test unixepoch-at-millisecond-precision-input-produces-seconds-precision-output {
SELECT unixepoch('2022-01-27 12:59:28.052');
} {1643288368}
} {1643288368}
do_execsql_test date-with-modifier-start-of-day {
SELECT date('2023-05-18 15:30:45', 'start of day');
} {2023-05-18}
do_execsql_test date-with-modifier-start-of-month {
SELECT date('2023-05-18', 'start of month');
} {2023-05-01}
do_execsql_test date-with-modifier-start-of-year {
SELECT date('2023-05-18', 'start of year');
} {2023-01-01}
do_execsql_test date-with-modifier-add-months {
SELECT date('2023-05-18', '+2 months');
} {2023-07-18}
do_execsql_test date-with-modifier-subtract-months {
SELECT date('2023-05-18', '-3 months');
} {2023-02-18}
do_execsql_test date-with-modifier-add-years {
SELECT date('2023-05-18', '+1 year');
} {2024-05-18}
do_execsql_test date-with-modifier-subtract-years {
SELECT date('2023-05-18', '-2 years');
} {2021-05-18}
do_execsql_test date-with-modifier-weekday {
SELECT date('2023-05-18', 'weekday 0');
} {2023-05-21}
do_execsql_test date-with-multiple-modifiers {
SELECT date('2023-05-18', '+1 month', '-10 days', 'start of year');
} {2023-01-01}
do_execsql_test date-with-subsec {
SELECT date('2023-05-18 15:30:45.123', 'subsec');
} {2023-05-18}
do_execsql_test time-with-modifier-add-hours {
SELECT time('2023-05-18 15:30:45', '+5 hours');
} {20:30:45}
do_execsql_test time-with-modifier-subtract-hours {
SELECT time('2023-05-18 15:30:45', '-2 hours');
} {13:30:45}
do_execsql_test time-with-modifier-add-minutes {
SELECT time('2023-05-18 15:30:45', '+45 minutes');
} {16:15:45}
do_execsql_test time-with-modifier-subtract-seconds {
SELECT time('2023-05-18 15:30:45', '-50 seconds');
} {15:29:55}
do_execsql_test time-with-subsec {
SELECT time('2023-05-18 15:30:45.123', 'subsec');
} {15:30:45.123}
do_execsql_test time-with-modifier-add {
SELECT time('15:30:45', '+15:30:15');
} {{07:01:00}}
do_execsql_test time-with-modifier-sub {
SELECT time('15:30:45', '-15:30:15');
} {{00:00:30}}
do_execsql_test date-with-modifier-add-months {
SELECT date('2023-01-31', '+1 month');
} {2023-03-03}
do_execsql_test date-with-modifier-subtract-months {
SELECT date('2023-03-31', '-1 month');
} {2023-03-03}
do_execsql_test date-with-modifier-add-months-large {
SELECT date('2023-01-31', '+13 months');
} {2024-03-02}
do_execsql_test date-with-modifier-subtract-months-large {
SELECT date('2023-01-31', '-13 months');
} {2021-12-31}
do_execsql_test date-with-modifier-february-leap-year {
SELECT date('2020-02-29', '+12 months');
} {2021-03-01}
do_execsql_test date-with-modifier-february-non-leap-year {
SELECT date('2019-02-28', '+12 months');
} {2020-02-28}
do_execsql_test date-with-modifier-invalid-date {
SELECT date('2023-02-15 15:30:45', '-0001-01-01 00:00');
} {2022-01-14}
do_execsql_test date-with-modifier-date {
SELECT date('2023-02-15 15:30:45', '+0001-01-01');
} {2024-03-16}
do_execsql_test datetime-with-modifier-datetime-pos {
SELECT datetime('2023-02-15 15:30:45', '+0001-01-01 15:30');
} {{2024-03-17 07:00:45}}
do_execsql_test datetime-with-modifier-datetime-neg {
SELECT datetime('2023-02-15 15:30:45', '+0001-01-01 15:30');
} {{2024-03-17 07:00:45}}
do_execsql_test datetime-with-modifier-datetime-large {
SELECT datetime('2023-02-15 15:30:45', '+7777-10-10 23:59');
} {{9800-12-26 15:29:45}}
do_execsql_test datetime-with-modifier-datetime-sub-large {
SELECT datetime('2023-02-15 15:30:45', '-2024-10-10 23:59');
} {{-0002-04-04 15:31:45}}
do_execsql_test datetime-with-timezone-utc {
SELECT datetime('2023-05-18 15:30:45Z');
} {{2023-05-18 15:30:45}}
do_execsql_test datetime-with-modifier-sub {
SELECT datetime('2023-12-12', '-0002-10-10 15:30:45');
} {{2021-02-01 08:29:15}}
do_execsql_test datetime-with-modifier-add {
SELECT datetime('2023-12-12', '+0002-10-10 15:30:45');
} {{2026-10-22 15:30:45}}
do_execsql_test time-with-multiple-modifiers {
SELECT time('2023-05-18 15:30:45', '+1 hours', '-20 minutes', '+15 seconds', 'subsec');
} {16:11:00.000}
do_execsql_test datetime-with-multiple-modifiers {
select datetime('2024-01-31', '+1 month', '+13 hours', '+5 minutes', '+62 seconds');
} {{2024-03-02 13:06:02}}
do_execsql_test datetime-with-weekday {
SELECT datetime('2023-05-18', 'weekday 3');
} {{2023-05-24 00:00:00}}
do_execsql_test unixepoch-subsec {
SELECT unixepoch('2023-05-18 15:30:45.123');
} {1684423845}
do_execsql_test unixepoch-invalid-date {
SELECT unixepoch('not-a-date');
} {{}}
do_execsql_test unixepoch-leap-second {
SELECT unixepoch('2015-06-30 23:59:60');
} {{}}
do_execsql_test unixepoch-negative-timestamp {
SELECT unixepoch('1969-12-31 23:59:59');
} {-1}
do_execsql_test unixepoch-large-date {
SELECT unixepoch('9999-12-31 23:59:59');
} {253402300799}
do_execsql_test datetime-with-timezone {
SELECT datetime('2023-05-19 01:30:45+03:00');
} {{2023-05-18 22:30:45}}
do_execsql_test julianday-fractional {
SELECT julianday('2023-05-18 15:30:45.123');
} {2460083.14635559}
do_execsql_test julianday-fractional-2 {
SELECT julianday('2000-01-01 12:00:00.500');
} {2451545.00000579}
do_execsql_test julianday-rounded-up {
SELECT julianday('2023-05-18 15:30:45.129');
} {2460083.14635566}
do_execsql_test julianday-with-timezone {
SELECT julianday('2023-05-18 15:30:45+02:00');
} {2460083.06302083}
do_execsql_test julianday-fractional-seconds {
SELECT julianday('2023-05-18 15:30:45.123');
} {2460083.14635559}
do_execsql_test julianday-time-only {
SELECT julianday('15:30:45');
} {2451545.14635417}
#
# TODO: fix precision issue
#
#do_execsql_test julianday-midnight {
# SELECT julianday('2023-05-18 00:00:00');
#} {2460082.5}
#do_execsql_test julianday-noon {
# SELECT julianday('2023-05-18 12:00:00');
#} {2460083.0}
#do_execsql_test julianday-fractional-zero {
# SELECT julianday('2023-05-18 00:00:00.000');
#} {2460082.5}
# same issue as above, we return .5000000 because we are using fmt precision
#do_execsql_test julianday-date-only {
# SELECT julianday('2023-05-18');
#} {2460082.5}