|
1 |
| - |
2 |
| -{# TODO: fully implement this and rename #} |
3 |
| -{# adapted from postgresql #} |
4 |
| -{% macro sqlite__datediff_broken(first_date, second_date, datepart) -%} |
5 |
| - |
| 1 | +{# |
| 2 | +-- Datetime precision in SQLite is only reliable down to the millisecond level, not microsecond level. |
| 3 | +-- The datetime calculations within this macro incorporate empirically determined thresholds (0.5, -0.5, etc.) |
| 4 | +-- to manage the rounding of differences more accurately across various units (days, weeks, etc.). |
| 5 | +-- These thresholds are chosen to appropriately round up or down, depending on the context of the calculation, |
| 6 | +-- ensuring that partial units are handled in a manner that best reflects their impact in real-world scenarios. |
| 7 | +-- This approach helps address edge cases where the exact boundary between units (like weeks) might otherwise |
| 8 | +-- lead to intuitively incorrect results, thus providing a more accurate and useful datediff function. |
| 9 | +#} |
| 10 | +{% macro sqlite__datediff(first_date, second_date, datepart) -%} |
| 11 | + {% set datepart = datepart.lower() %} |
6 | 12 | {% if datepart == 'year' %}
|
7 |
| - (strftime('%Y', {{second_date}}) - strftime('%Y', {{first_date}})) |
8 |
| - {# |
9 |
| - {% elif datepart == 'quarter' %} |
10 |
| - ({{ datediff(first_date, second_date, 'year') }} * 4 + date_part('quarter', ({{second_date}})::date) - date_part('quarter', ({{first_date}})::date)) |
11 |
| - #} |
| 13 | + (strftime('%Y', {{ second_date }}) - strftime('%Y', {{ first_date }})) |
12 | 14 | {% elif datepart == 'month' %}
|
13 |
| - (({{ datediff(first_date, second_date, 'year') }} * 12 + strftime('%m', {{second_date}})) - strftime('%m', {{first_date}})) |
| 15 | + ((strftime('%Y', {{ second_date }}) - strftime('%Y', {{ first_date }})) * 12) + |
| 16 | + (strftime('%m', {{ second_date }}) - strftime('%m', {{ first_date }})) |
14 | 17 | {% elif datepart == 'day' %}
|
15 |
| - (floor(cast(strftime('%s', {{second_date}}) - strftime('%s', {{first_date}}) as real) / 86400) + |
16 |
| - case when {{second_date}} <= strftime('%Y-%m-%d 23:59:59.999999', {{first_date}}) then -1 else 0 end) |
| 18 | + CASE |
| 19 | + WHEN |
| 20 | + ((strftime('%s', {{ second_date }}) - strftime('%s', {{ first_date }})) / 86400.0) >= 0 |
| 21 | + THEN CEIL( |
| 22 | + (strftime('%s', {{ second_date }}) - strftime('%s', {{ first_date }})) / 86400.0 |
| 23 | + ) |
| 24 | + ELSE FLOOR( |
| 25 | + (strftime('%s', {{ second_date }}) - strftime('%s', {{ first_date }})) / 86400.0 |
| 26 | + ) |
| 27 | + END |
17 | 28 | {% elif datepart == 'week' %}
|
18 |
| - ({{ datediff(first_date, second_date, 'day') }} / 7 + case |
19 |
| - when strftime('%w', {{first_date}}) <= strftime('%w', {{second_date}}) then |
20 |
| - case when {{first_date}} <= {{second_date}} then 0 else -1 end |
21 |
| - else |
22 |
| - case when {{first_date}} <= {{second_date}} then 1 else 0 end |
23 |
| - end) |
| 29 | + CASE |
| 30 | + WHEN |
| 31 | + ((strftime('%s', {{ second_date }}) - strftime('%s', {{ first_date }})) / 604800.0) >= 0.285715 |
| 32 | + THEN CEIL( |
| 33 | + (strftime('%s', {{ second_date }}) - strftime('%s', {{ first_date }})) / 604800.0 |
| 34 | + ) |
| 35 | + WHEN |
| 36 | + ((strftime('%s', {{ second_date }}) - strftime('%s', {{ first_date }})) / 604800.0) <= -0.285715 |
| 37 | + THEN FLOOR( |
| 38 | + (strftime('%s', {{ second_date }}) - strftime('%s', {{ first_date }})) / 604800.0 |
| 39 | + ) |
| 40 | + ELSE CAST( |
| 41 | + (strftime('%s', {{ second_date }}) - strftime('%s', {{ first_date }})) / 604800.0 |
| 42 | + AS INTEGER) |
| 43 | + END |
24 | 44 | {% elif datepart == 'hour' %}
|
25 |
| - {# ({{ datediff(first_date, second_date, 'day') }} * 24 + strftime("%H", {{second_date}}) - strftime("%H", {{first_date}})) #} |
26 |
| - (ceil(cast(strftime('%s', {{second_date}}) - strftime('%s', {{first_date}}) as real) / 3600)) |
| 45 | + CASE |
| 46 | + WHEN |
| 47 | + ((strftime('%s', {{ second_date }}) - strftime('%s', {{ first_date }})) / 3600.0) >= 0 |
| 48 | + THEN CEIL( |
| 49 | + (strftime('%s', {{ second_date }}) - strftime('%s', {{ first_date }})) / 3600.0 |
| 50 | + ) |
| 51 | + ELSE FLOOR( |
| 52 | + (strftime('%s', {{ second_date }}) - strftime('%s', {{ first_date }})) / 3600.0 |
| 53 | + ) |
| 54 | + END |
27 | 55 | {% elif datepart == 'minute' %}
|
28 |
| - {# ({{ datediff(first_date, second_date, 'hour') }} * 60 + strftime("%M", {{second_date}}) - strftime("%M", {{first_date}})) #} |
29 |
| - (ceil(cast(strftime('%s', {{second_date}}) - strftime('%s', {{first_date}}) as real) / 60)) |
| 56 | + CASE |
| 57 | + WHEN |
| 58 | + ((strftime('%s', {{ second_date }}) - strftime('%s', {{ first_date }})) / 60.0) >= 0 |
| 59 | + THEN CEIL( |
| 60 | + (strftime('%s', {{ second_date }}) - strftime('%s', {{ first_date }})) / 60.0 |
| 61 | + ) |
| 62 | + ELSE FLOOR( |
| 63 | + (strftime('%s', {{ second_date }}) - strftime('%s', {{ first_date }})) / 60.0 |
| 64 | + ) |
| 65 | + END |
30 | 66 | {% elif datepart == 'second' %}
|
31 |
| - (strftime('%s', {{second_date}}) - strftime('%s', {{first_date}})) |
32 |
| - {# |
| 67 | + CASE |
| 68 | + WHEN |
| 69 | + ((strftime('%s', {{ second_date }}) + cast(substr(strftime('%f', {{ second_date }}), instr(strftime('%f', {{ second_date }}), '.') + 1) as real) / 1000.0) - |
| 70 | + (strftime('%s', {{ first_date }}) + cast(substr(strftime('%f', {{ first_date }}), instr(strftime('%f', {{ first_date }}), '.') + 1) as real) / 1000.0)) >= 0 |
| 71 | + THEN CEIL( |
| 72 | + (strftime('%s', {{ second_date }}) + cast(substr(strftime('%f', {{ second_date }}), instr(strftime('%f', {{ second_date }}), '.') + 1) as real) / 1000.0) - |
| 73 | + (strftime('%s', {{ first_date }}) + cast(substr(strftime('%f', {{ first_date }}), instr(strftime('%f', {{ first_date }}), '.') + 1) as real) / 1000.0) |
| 74 | + ) |
| 75 | + ELSE FLOOR( |
| 76 | + (strftime('%s', {{ second_date }}) + cast(substr(strftime('%f', {{ second_date }}), instr(strftime('%f', {{ second_date }}), '.') + 1) as real) / 1000.0) - |
| 77 | + (strftime('%s', {{ first_date }}) + cast(substr(strftime('%f', {{ first_date }}), instr(strftime('%f', {{ first_date }}), '.') + 1) as real) / 1000.0) |
| 78 | + ) |
| 79 | + END |
33 | 80 | {% elif datepart == 'millisecond' %}
|
34 |
| - ({{ datediff(first_date, second_date, 'minute') }} * 60000 + floor(date_part('millisecond', ({{second_date}})::timestamp)) - floor(date_part('millisecond', ({{first_date}})::timestamp))) |
35 |
| - {% elif datepart == 'microsecond' %} |
36 |
| - ({{ datediff(first_date, second_date, 'minute') }} * 60000000 + floor(date_part('microsecond', ({{second_date}})::timestamp)) - floor(date_part('microsecond', ({{first_date}})::timestamp))) |
37 |
| - #} |
| 81 | + ((1000 * (strftime('%s', {{ second_date }}))) + cast(substr(strftime('%f', {{ second_date }}), instr(strftime('%f', {{ second_date }}), '.') + 1) as integer) - |
| 82 | + (1000 * (strftime('%s', {{ first_date }}))) + cast(substr(strftime('%f', {{ first_date }}), instr(strftime('%f', {{ first_date }}), '.') + 1) as integer)) |
38 | 83 | {% else %}
|
39 |
| - {{ exceptions.raise_compiler_error("Unsupported datepart for macro datediff in sqlite: {!r}".format(datepart)) }} |
| 84 | + {{ exceptions.raise_compiler_error("Unsupported datepart for macro datediff in SQLite: '" ~ datepart ~ "'") }} |
40 | 85 | {% endif %}
|
41 |
| - |
42 | 86 | {%- endmacro %}
|
0 commit comments