From 3221bc298d8ea16c91a8bd64ae2fbb6a8da3bf80 Mon Sep 17 00:00:00 2001 From: silviu stanimir Date: Fri, 17 Nov 2023 07:47:38 +0100 Subject: [PATCH] feat: implement dateadd macro --- README.md | 7 ++++++ macros/multiple_databases/dateadd.sql | 33 +++++++++++++++++++++++++++ 2 files changed, 40 insertions(+) create mode 100644 macros/multiple_databases/dateadd.sql diff --git a/README.md b/README.md index 055dd25..df8dc57 100644 --- a/README.md +++ b/README.md @@ -28,6 +28,7 @@ This dbt package contains macros for SQL functions to run the dbt project on mul - [as_varchar](#as_varchar-source) - [charindex](#charindex-source) - [create_index](#create_index-source) + - [date_add](#date_add-source) - [date_from_timestamp](#date_from_timestamp-source) - [datediff](#datediff-source) - [string_agg](#string_agg-source) @@ -86,6 +87,12 @@ In case you want to create the index on a source table, refer to the table using ) }} ``` +#### dateadd ([source](macros/multiple_databases/dateadd.sql)) +This macro adds a specified number value (as a signed integer) of the specified datepart to an input date or datetime and then returns that modified value. The datepart can be any of the following values: year, quarter, month, week, day, hour, minute, second, millisecond. + +Usage: +`{{ pm_utils.dateadd('[datepart]', [number], '[expression]') }}` + #### date_from_timestamp ([source](macros/multiple_databases/date_from_timestamp.sql)) This macro extracts the date part from a datetime field. diff --git a/macros/multiple_databases/dateadd.sql b/macros/multiple_databases/dateadd.sql new file mode 100644 index 0000000..b095b87 --- /dev/null +++ b/macros/multiple_databases/dateadd.sql @@ -0,0 +1,33 @@ +{%- macro dateadd(datepart, number, date_or_datetime_field) -%} +{%- if target.type == 'snowflake' -%} + dateadd({{ datepart }}, {{ number }}, try_to_timestamp(to_varchar({{ date_or_datetime_field }}))) +{%- elif target.type == 'sqlserver' -%} + dateadd({{ datepart }}, {{ number }}, try_convert(datetime2, {{ date_or_datetime_field }})) +{%- elif target.type == 'databricks' -%} + {%- set datetime_field -%} + try_to_timestamp({{ date_or_datetime_field }}) + {%- endset -%} + {%- set time_field -%} + unix_millis({{ datetime_field }}) - unix_millis(date_trunc('DD', {{ datetime_field }})) + {%- endset -%} + {%- if datepart == 'millisecond' -%} + timestamp_millis(unix_millis({{ datetime_field }}) + {{ number }}) + {%- elif datepart == 'second' -%} + timestamp_millis(unix_millis({{ datetime_field }}) + {{ number }}*1000) + {%- elif datepart == 'minute' -%} + timestamp_millis(unix_millis({{ datetime_field }}) + {{ number }}*60000) + {%- elif datepart == 'hour' -%} + timestamp_millis(unix_millis({{ datetime_field }}) + {{ number }}*3600000) + {%- elif datepart == 'day' -%} + timestamp_millis(unix_millis(try_to_timestamp(date_add(to_date({{ datetime_field }}), {{ number }}))) + {{ time_field }}) + {%- elif datepart == 'week' -%} + timestamp_millis(unix_millis(try_to_timestamp(date_add(to_date({{ datetime_field }}), {{ number }}*7))) + {{ time_field }}) + {%- elif datepart == 'month' -%} + timestamp_millis(unix_millis(try_to_timestamp(add_months(to_date({{ datetime_field }}), {{ number }}))) + {{ time_field }}) + {%- elif datepart == 'quarter' -%} + timestamp_millis(unix_millis(try_to_timestamp(add_months(to_date({{ datetime_field }}), {{ number }}*3))) + {{ time_field }}) + {%- elif datepart == 'year' -%} + timestamp_millis(unix_millis(try_to_timestamp(add_months(to_date({{ datetime_field }}), {{ number }}*12))) + {{ time_field }}) + {%- endif -%} +{%- endif -%} +{%- endmacro -%}