├── .DS_Store ├── .circleci └── config.yml ├── .github ├── bug_report.md ├── feature_request.md └── pull_request_template.md ├── .gitignore ├── .vscode └── settings.json ├── LICENSE.md ├── README.md ├── dbt_project.yml ├── docs ├── catalog.json ├── index.html ├── manifest.json └── run_results.json ├── helper ├── _resources │ ├── 01-discovery.py │ └── config │ │ ├── redshift │ │ ├── dt_mappings.json │ │ ├── function_mappings.json │ │ ├── functionlist.csv │ │ └── syntax_mappings.json │ │ └── snowflake │ │ ├── blockedfunctionlist.csv │ │ ├── dt_mappings.json │ │ ├── function_mappings.json │ │ ├── functionlist.csv │ │ ├── springbrickstests.csv │ │ └── syntax_mappings.json ├── convert_to_databricks.py ├── discoveryutil.py ├── function_to_macro_discovery.py └── pierunner.py.py ├── integration_tests ├── dbt_project.yml ├── functionak.sql ├── macros │ ├── README.md │ ├── array_agg.sql │ ├── array_cat.sql │ ├── array_compact.sql │ ├── array_construct.sql │ ├── array_intersection.sql │ ├── array_size.sql │ ├── array_to_string.sql │ ├── base64_decode_binary.sql │ ├── base64_decode_string.sql │ ├── base64_encode.sql │ ├── bitand.sql │ ├── charindex.sql │ ├── contains.sql │ ├── current_schema.sql │ ├── date_from_parts.sql │ ├── dateaddog.sql │ ├── dayname.sql │ ├── dayofweekiso.sql │ ├── dbt_housekeeping.sql │ ├── div0.sql │ ├── dt_convert_money.sql │ ├── endswith.sql │ ├── equal_null.sql │ ├── exclude.sql │ ├── from_utc_timestamp.sql │ ├── getdate.sql │ ├── hex_decode_string.sql │ ├── insert.sql │ ├── is_null_value.sql │ ├── json_extract_path_text.sql │ ├── listagg.sql │ ├── md5_binary.sql │ ├── monthname.sql │ ├── nullifzero.sql │ ├── parse_json.sql │ ├── previous_day.sql │ ├── seq1.sql │ ├── seq2.sql │ ├── seq4.sql │ ├── seq8.sql │ ├── sha1hex.sql │ ├── sha2_hex.sql │ ├── split_part.sql │ ├── square.sql │ ├── startswith.sql │ ├── strtok.sql │ ├── strtok_to_array.sql │ ├── sysdate.sql │ ├── systimestamp.sql │ ├── timediff.sql │ ├── timestamp_from_parts.sql │ ├── timestampadd.sql │ ├── timestampdiff.sql │ ├── to_array.sql │ ├── to_binary.sql │ ├── to_boolean.sql │ ├── to_char.sql │ ├── to_decimal.sql │ ├── to_number.sql │ ├── to_numeric.sql │ ├── to_time.sql │ ├── to_timestamp_ntz.sql │ ├── to_varchar.sql │ ├── try_cast.sql │ ├── try_to_decimal.sql │ ├── try_to_number.sql │ ├── try_to_numeric.sql │ ├── uniform.sql │ ├── uuid_string.sql │ ├── week.sql │ ├── weekiso.sql │ ├── yearofweek.sql │ ├── yearofweekiso.sql │ └── zeroifnull.sql ├── profiles.yml ├── regexit.py ├── seeds │ └── springbrickstests.csv ├── syntaxak.sql ├── tests │ ├── assert_base64_encode.sql │ ├── assert_contains.sql │ ├── assert_date_from_parts.sql │ ├── assert_dayname.sql │ ├── assert_dayofweekiso.sql │ ├── assert_json_extract_path_text.sql │ ├── assert_listagg.sql │ ├── assert_listaggdistinct.sql │ ├── assert_md5_binary.sql │ ├── assert_monthname.sql │ ├── assert_startswith.sql │ ├── assert_strtok_to_array.sql │ ├── assert_to_array.sql │ ├── assert_to_boolean.sql │ ├── assert_to_time.sql │ ├── assert_week.sql │ ├── assert_zeroifnull.sql │ ├── asset_to_decimal.sql │ ├── asset_to_number.sql │ ├── asset_to_numeric.sql │ ├── asset_try_to_decimal.sql │ ├── asset_try_to_number.sql │ ├── asset_try_to_numeric.sql │ ├── readme.md │ ├── timediff.sql │ ├── timestampadd.sql │ └── timestampdiff.sql ├── tresak.py └── unoak.lkml ├── macros ├── .DS_Store ├── redshift │ ├── README.md │ ├── convert.sql │ ├── date_part.sql │ ├── date_trunc.sql │ ├── datediff.sql │ ├── dexp.sql │ ├── dlog1.sql │ ├── dlog10.sql │ ├── getdate.sql │ ├── hll.sql │ ├── hll_cardinality.sql │ ├── hll_combine.sql │ ├── hll_combine_skeetches.sql │ ├── hll_create_sketch .sql │ ├── isnull.sql │ ├── strtol.sql │ ├── sysdate.sql │ ├── texttointalt.sql │ └── texttonumericalt.sql └── snowflake │ ├── README.md │ ├── array_agg.sql │ ├── array_cat.sql │ ├── array_compact.sql │ ├── array_construct.sql │ ├── array_intersection.sql │ ├── array_size.sql │ ├── array_slice.sql │ ├── array_to_string.sql │ ├── base64_decode_binary.sql │ ├── base64_decode_string.sql │ ├── base64_encode.sql │ ├── bitand.sql │ ├── booland_agg.sql │ ├── boolor_agg.sql │ ├── charindex.sql │ ├── contains.sql │ ├── current_schema.sql │ ├── date_from_parts.sql │ ├── dateaddog.sql │ ├── dayname.sql │ ├── dayofweekiso.sql │ ├── dbt_housekeeping.sql │ ├── div0.sql │ ├── dt_convert_money.sql │ ├── endswith.sql │ ├── equal_null.sql │ ├── exclude.sql │ ├── from_utc_timestamp.sql │ ├── getdate.sql │ ├── hex_decode_string.sql │ ├── hll_estimate.sql │ ├── insert.sql │ ├── is_null_value.sql │ ├── json_extract_path_text.sql │ ├── listagg.sql │ ├── md5_binary.sql │ ├── monthname.sql │ ├── nullifzero.sql │ ├── parse_json.sql │ ├── previous_day.sql │ ├── seq1.sql │ ├── seq2.sql │ ├── seq4.sql │ ├── seq8.sql │ ├── sha1hex.sql │ ├── sha2_hex.sql │ ├── split_part.sql │ ├── square.sql │ ├── startswith.sql │ ├── strtok.sql │ ├── strtok_to_array.sql │ ├── sysdate.sql │ ├── systimestamp.sql │ ├── timediff.sql │ ├── timestamp_from_parts.sql │ ├── timestamp_ntz_from_parts.sql │ ├── timestampadd.sql │ ├── timestampdiff.sql │ ├── to_array.sql │ ├── to_binary.sql │ ├── to_boolean.sql │ ├── to_char.sql │ ├── to_decimal.sql │ ├── to_number.sql │ ├── to_numeric.sql │ ├── to_time.sql │ ├── to_timestamp_ntz.sql │ ├── to_varchar.sql │ ├── try_cast.sql │ ├── try_to_decimal.sql │ ├── try_to_number.sql │ ├── try_to_numeric.sql │ ├── uniform.sql │ ├── uuid_string.sql │ ├── variance_samp.sql │ ├── week.sql │ ├── weekiso.sql │ ├── yearofweek.sql │ ├── yearofweekiso.sql │ └── zeroifnull.sql ├── models ├── redshift │ ├── customerrs.sql │ ├── r1 │ │ └── customerrs.sql │ └── r2 │ │ └── customerrs.sql └── snowflake │ ├── customer.sql │ └── lineitem.sql ├── profiles.yml ├── seeds ├── redshift │ └── functionlistrs.csv └── snowflake │ ├── blockedfunctionlist.csv │ ├── functionlist.csv │ ├── springbrickstests.csv │ └── wipfunctionlist.csv ├── tests ├── Redshift │ ├── assert_convert.sql │ ├── assert_strtol.sql │ ├── dlog1.sql │ ├── dlog10.sql │ ├── hll.sql │ ├── test_dexp.sql │ └── test_texttonumericalt.sql └── Snowflake │ ├── README.md │ ├── assert_base64_encode.sql │ ├── assert_contains.sql │ ├── assert_date_from_parts.sql │ ├── assert_dayname.sql │ ├── assert_dayofweekiso.sql │ ├── assert_json_extract_path_text.sql │ ├── assert_listagg.sql │ ├── assert_listaggdistinct.sql │ ├── assert_md5_binary.sql │ ├── assert_monthname.sql │ ├── assert_startswith.sql │ ├── assert_strtok_to_array.sql │ ├── assert_to_array.sql │ ├── assert_to_boolean.sql │ ├── assert_to_time.sql │ ├── assert_week.sql │ ├── assert_zeroifnull.sql │ ├── asset_to_decimal.sql │ ├── asset_to_number.sql │ ├── asset_to_numeric.sql │ ├── asset_try_to_decimal.sql │ ├── asset_try_to_number.sql │ ├── asset_try_to_numeric.sql │ ├── timediff.sql │ ├── timestampadd.sql │ └── timestampdiff.sql └── tmp ├── beyondsqltest ├── testlookmlfiles │ ├── dos.lkml │ ├── tres.lkml │ └── uno.lkml └── testpyfiles │ ├── dos.py │ ├── tres.py │ └── uno.py ├── redshift └── customerrs.sql └── snow ├── customerdb.sql └── lineitemdb.sql /.DS_Store: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/techvaquero/lakehouse_utils/c27dc99d14c71498c966fbbea3615a74029eb78e/.DS_Store -------------------------------------------------------------------------------- /.circleci/config.yml: -------------------------------------------------------------------------------- 1 | version: 2.1 2 | 3 | 4 | name: Circle 5 | on: 6 | pull_request: 7 | branches: 8 | - main 9 | 10 | jobs: 11 | build: 12 | docker: 13 | - image: cimg/python:3.9.9 14 | 15 | 16 | 17 | steps: 18 | - checkout 19 | 20 | 21 | 22 | - run: 23 | name: "Setup dbt" 24 | command: | 25 | set -x 26 | 27 | python -m venv dbt_venv 28 | . dbt_venv/bin/activate 29 | 30 | python -m pip install --upgrade pip setuptools 31 | python -m pip install dbt-databricks==1.5.5 32 | pwd 33 | python3 helper/convert_to_databricks.py --sourcedb "redshift" --dir_path "redshift/" --parse_mode 'syntax' --parse_first 'syntax' 34 | python3 helper/convert_to_databricks.py --sourcedb "redshift" --dir_path "tmp/beyondsqltest/testpyfiles" --parse_mode 'syntax' --parse_first 'syntax' --dir_mode 'nondbt' --file_type 'py' --except_list 'uno.py','dos.py' 35 | python3 helper/convert_to_databricks.py --sourcedb "redshift" --dir_path "tmp/beyondsqltest/testlookmlfiles" --parse_mode 'syntax' --parse_first 'syntax' --dir_mode 'lookml' --file_type 'lkml' --except_list 'dos.lkml','tres.lkml' 36 | python3 integration_tests/regexit.py 37 | 38 | - store_artifacts: 39 | path: integration_tests/logs 40 | - store_artifacts: 41 | path: integration_tests/target 42 | 43 | workflows: 44 | 45 | test-all: 46 | jobs: 47 | - build: 48 | context: 49 | - profile-databricks 50 | -------------------------------------------------------------------------------- /.github/bug_report.md: -------------------------------------------------------------------------------- 1 | --- 2 | name: Bug report 3 | about: Report a bug or an issue you've found with this package 4 | title: '' 5 | labels: bug, triage 6 | assignees: '' 7 | 8 | --- 9 | 10 | ### Describe the bug 11 | 14 | 15 | ### Steps to reproduce 16 | 19 | 20 | ### Expected results 21 | 24 | 25 | ### Actual results 26 | 29 | 30 | ### Screenshots and log output 31 | 34 | 35 | ### System information 36 | **The contents of your `packages.yml` file:** 37 | 38 | **Which database are you using dbt with?** 39 | - [ ] postgres 40 | - [ ] redshift 41 | - [ ] bigquery 42 | - [ ] snowflake 43 | - [ ] other (specify: ____________) 44 | 45 | 46 | **The output of `dbt --version`:** 47 | ``` 48 | 49 | ``` 50 | 51 | **The operating system you're using:** 52 | 53 | **The output of `python --version`:** 54 | 55 | ### Additional context 56 | 59 | 60 | ### Are you interested in contributing the fix? 61 | 64 | -------------------------------------------------------------------------------- /.github/feature_request.md: -------------------------------------------------------------------------------- 1 | --- 2 | name: Feature request 3 | about: Suggest an idea for this package 4 | title: '' 5 | labels: enhancement, triage 6 | assignees: '' 7 | 8 | --- 9 | 10 | ### Describe the feature 11 | A clear and concise description of what you want to happen. 12 | 13 | ### Describe alternatives you've considered 14 | A clear and concise description of any alternative solutions or features you've considered. 15 | 16 | ### Additional context 17 | Is this feature database-specific? Which database(s) is/are relevant? Please include any other relevant context here. 18 | 19 | ### Who will this benefit? 20 | What kind of use case will this feature be useful for? Please be specific and provide examples, this will help us prioritize properly. 21 | 22 | ### Are you interested in contributing this feature? 23 | 26 | -------------------------------------------------------------------------------- /.github/pull_request_template.md: -------------------------------------------------------------------------------- 1 | ## Description & motivation 2 | 5 | 6 | ## Checklist 7 | - [ ] I have verified that these changes work locally 8 | - [ ] I have updated the README.md (if applicable) 9 | - [ ] I have verified that existing unit tests pass (may need to run dbt seed first) 10 | - [ ] I have added a unit test for each new macro I created and I have verifed that these new unit tests pass. 11 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | target/ 2 | dbt_packages/ 3 | logs/ 4 | -------------------------------------------------------------------------------- /.vscode/settings.json: -------------------------------------------------------------------------------- 1 | { 2 | "python.envFile": "${workspaceFolder}/.databricks/.databricks.env", 3 | "databricks.python.envFile": "${workspaceFolder}/.env", 4 | "jupyter.interactiveWindow.cellMarker.codeRegex": "^# COMMAND ----------|^# Databricks notebook source|^(#\\s*%%|#\\s*\\|#\\s*In\\[\\d*?\\]|#\\s*In\\[ \\])", 5 | "jupyter.interactiveWindow.cellMarker.default": "# COMMAND ----------" 6 | } -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | ### lakehouse_utils: 2 | 3 | The purpose of the lakehouse utils package is threefold: 4 | 5 | I) Expedite the time and level of effort for migrating pipelines from cloud data warehouses to the Lakehouse (ie dbt + databricks). This is done by transpiling functions that are not natively available in spark sql to compatible spark sql functions that take in the same input(s) and render the same outputs. This is done via either DBT macros (feel free to reference the macros directory) or in place regex conversions. 6 | 7 | II) Be a centralized source of truth for warehouse function mapping to Databricks function mapping. Also surface instances where certain functions can not be automated and manual intervention is required. You can find the full list of supported functions in the functionlist.csv in the seed directory; you can also find further information in the read.me in the macros directory. 8 | 9 | III) Surface best practices around unit tests to instill confidence that the macros are robust and reliable (feel free to reference the tests directory). 10 | 11 | ### Installation instructions: 12 | 13 | I) Include this package in your packages.yml — check [here](https://github.com/rlsalcido24/lakehouse_utils/releases/tag/v1.0.1) for the latest version number. 14 | 15 | II) Run dbt deps 16 | 17 | III) Execute dbt seed -- this project includes a CSV that must be seeded for automated transpilation. 18 | 19 | ### Database support: 20 | 21 | This package has been tested on Snowflake, Redshift, and Databricks. 22 | 23 | ### Manual 'Hello World' CUJ: 24 | 25 | To get a quick sense of what this module offers, you can reference and run the models in the models directory. Here are the relevant steps: 26 | 27 | I) Insert the relevant values into the profiles.yml based on your warehouse and lakehouse credentials. 28 | 29 | II) Build the Snowflake models by executing dbt run --target snow and the Redshift models by executing dbt run --target redshift. 30 | 31 | III) Build the Databricks models by temporarily updating the models_path key in profiles.yml to be tmp/snowflake or tmp/redshift and executing dbt run --target databricks. 32 | 33 | IV) Observe that when when the models build on Databricks they transpile the Snowflake/Redshift functions that invoke macros (wrapped in curly braces). Also observe that while syntax is slightly different in each system the end results are still the same. Also note that manually 'migrating' these two models from scratch should take no longer than 5 mins-- it is just a matter of wrapping the relevant function in braces and wrapping the input parameters in quotes. 34 | 35 | ### Automated 'to the moon' CUJ 36 | 37 | I) Create a seperate dev branch of your dbt project. Execute dbt seed (if you haven't already). Run the helper convert_to_databricks.py file (either locally or within Databricks). Obvserve that all your Snowflake/Redshift models have now been automatically refactored to reference relevant macros, therefore making it possible to build these models in Databricks. 38 | 39 | II) dbt run. 40 | 41 | III) Execute unit tests to ensure that the models built in Databricks match the models built on Snowflake/Redshift. 42 | 43 | IV) Once you have sufficient confidence merge the dev branch into master and update your dbt run to refrence the transpiled logic. 44 | 45 | V) Build models in both systems until sufficient confidence is instilled to run the models solely on one system. 46 | 47 | ### Local Version - Databricks Converter locally 48 | 49 | There is also a convert_to_databricks python file that can convert the models in place in a local environment. 50 | 51 | This function also contains additional abilities such as: 52 | 53 | I) Ability to configure and inject arbitrary regex syntax mappings source_pattern --> target_pattern. 54 | II) Ability to write out converted results to separate folder 55 | III) Ability to run as a package or standalone locally 56 | IV) Ability execute locally without needing to connect or import into Databricks for conversion. 57 | 58 | Example Command: 59 | python3 ./convert_to_databricks.py --sourcedb redshift --dir_path "redshift/" --parse_mode 'all' --parse_first 'syntax' 60 | 61 | For the full list of avail vars, use the --h flag or look at the code base. Other examples also exist in the pierunner doc in the helper directory as well! 62 | 63 | 64 | ## Macros: 65 | 66 | ### zeroifnull ([source](https://github.com/rlsalcido24/lakehouse_utils/blob/main/macros/zeroifnull.sql)) 67 | 68 | This macro takes in a column input and leverages the nvl function to return 0 if the input is null. 69 | ``` 70 | {% macro zeroifnull(column_name) %} 71 | nvl({{column_name}}, 0) 72 | {% endmacro %} 73 | ``` 74 | 75 | Arguments: 76 | 77 | a) Column name 78 | 79 | ### to_number ([source](https://github.com/rlsalcido24/lakehouse_utils/blob/main/macros/to_number.sql)) 80 | 81 | This macro takes in an expression and optional format/precision/scale and returns a decimal with default formatting or the specified formatting. 82 | ``` 83 | {% macro to_number(expr, format, precision, scale) %} 84 | 85 | 86 | {% if scale %} 87 | 88 | cast({{expr}} as decimal({{precision}}, {{scale}})) 89 | 90 | 91 | {% elif precision %} 92 | 93 | cast({{expr}} as decimal({{format}}, {{precision}})) 94 | 95 | 96 | {% elif format %} 97 | 98 | to_number({{expr}}, "{{format}}") 99 | 100 | 101 | {% else %} 102 | 103 | cast({{expr}} as decimal(38, 0)) 104 | 105 | {% endif %} 106 | 107 | {% endmacro %} 108 | ``` 109 | 110 | Arguments: 111 | 112 | a) Expr
113 | b) format (optional)
114 | c) precision (optional)
115 | d) scale (optional) 116 | 117 | ### timestampadd ([source](https://github.com/rlsalcido24/lakehouse_utils/blob/main/macros/timestampadd.sql)) 118 | 119 | This macro takes in a time unit and adds the unit to an existing timestamp. 120 | ``` 121 | {% macro timestampadd(unit, measure, base) %} 122 | CASE 123 | WHEN lower({{unit}}) = 'year' THEN {{base}} + make_interval({{measure}}) 124 | WHEN lower({{unit}}) = 'month' THEN {{base}} + make_interval(0, {{measure}}) 125 | WHEN lower({{unit}}) = 'day' THEN {{base}} + make_interval(0, 0, 0, {{measure}}) 126 | WHEN lower({{unit}}) = 'hour' THEN {{base}} + make_interval(0, 0, 0, 0, {{measure}}) 127 | WHEN lower({{unit}}) = 'minute' THEN {{base}} + make_interval(0, 0, 0, 0, 0, {{measure}}) 128 | WHEN lower({{unit}}) = 'second' THEN {{base}} + make_interval(0, 0, 0, 0, 0, 0, {{measure}}) 129 | END 130 | {% endmacro %} 131 | ``` 132 | 133 | Arguments: 134 | 135 | a) time unit
136 | b) measure (ie number of time units to add)
137 | c) base timestamp 138 | 139 | ### timestampdiff ([source](https://github.com/rlsalcido24/lakehouse_utils/blob/main/macros/timestampdiff.sql)) 140 | 141 | This macro takes in two timestamps and calculates the difference by quantity of units. 142 | ``` 143 | {% macro timestampdiff(unit, arg1,arg2) %} 144 | CASE 145 | WHEN lower({{unit}}) = 'year' THEN EXTRACT(YEAR FROM {{arg2}}) - EXTRACT(YEAR FROM {{arg1}}) 146 | WHEN lower({{unit}}) = 'month' THEN (EXTRACT(YEAR FROM {{arg2}}) * 12 + EXTRACT(MONTH FROM 147 | {{arg2}})) 148 | - (EXTRACT(YEAR FROM {{arg1}}) * 12 + EXTRACT(MONTH FROM {{arg1}})) 149 | WHEN lower({{unit}}) = 'day' THEN datediff(CAST({{arg2}} AS DATE), CAST({{arg1}} AS DATE)) 150 | WHEN lower({{unit}}) = 'hour' THEN EXTRACT(HOUR FROM {{arg2}}) - EXTRACT(HOUR FROM {{arg1}}) 151 | WHEN lower({{unit}}) = 'minute' THEN (EXTRACT(HOUR FROM {{arg2}}) * 60 + EXTRACT(MINUTE FROM 152 | {{arg2}})) 153 | - (EXTRACT(HOUR FROM {{arg1}}) * 60 + EXTRACT(MINUTE FROM {{arg1}})) 154 | WHEN lower({{unit}}) = 'second' THEN (EXTRACT(HOUR FROM {{arg2}}) * 3600 + EXTRACT(MINUTE FROM 155 | {{arg2}}) * 60 + EXTRACT(SECOND FROM {{arg2}})) 156 | - (EXTRACT(HOUR FROM {{arg2}}) * 3600 + EXTRACT(MINUTE FROM {{arg2}}) * 157 | 60 + EXTRACT(SECOND FROM {{arg2}})) 158 | END 159 | {% endmacro %} 160 | ``` 161 | 162 | Arguments: 163 | 164 | a) unit
165 | b) timestamp being subtracted
166 | c) timesamp being subtracted from 167 | 168 | ### dayname ([source](https://github.com/rlsalcido24/lakehouse_utils/blob/main/macros/dayname.sql)) 169 | 170 | This macro takes in a date and returns a string for day of week of that date. 171 | ``` 172 | {% macro dayname(arg) %} 173 | CASE 174 | WHEN datediff(CAST({{arg}} AS DATE), DATE'1799-12-29') % 7 = 0 THEN 'Sun' 175 | WHEN datediff(CAST({{arg}} AS DATE), DATE'1799-12-29') % 7 = 1 THEN 'Mon' 176 | WHEN datediff(CAST({{arg}} AS DATE), DATE'1799-12-29') % 7 = 2 THEN 'Tue' 177 | WHEN datediff(CAST({{arg}} AS DATE), DATE'1799-12-29') % 7 = 3 THEN 'Wed' 178 | WHEN datediff(CAST({{arg}} AS DATE), DATE'1799-12-29') % 7 = 4 THEN 'Thu' 179 | WHEN datediff(CAST({{arg}} AS DATE), DATE'1799-12-29') % 7 = 5 THEN 'Fri' 180 | ELSE 'Sat' END 181 | {% endmacro %} 182 | ``` 183 | 184 | Arguments: 185 | 186 | a) date 187 | 188 | ### Next Steps: 189 | 190 | Note that we gladly welcome contributions from the partners and from the community-- if intersted please submit a pull request! We can particularly use support with increasing our surface area of supported functions. When submitting a PR please include a unit test for each new macro added-- as long as any new unit tests pass, and existing tests continue to pass, we should be able to GTM (example pr template in .github directory). If you have a request to support a particular function please do log it as an enhancement in issues and happy building!! 191 | -------------------------------------------------------------------------------- /dbt_project.yml: -------------------------------------------------------------------------------- 1 | name: 'lakehouse_utils' 2 | version: '1.0.0' 3 | config-version: 2 4 | require-dbt-version: ">=1.0.0" 5 | profile: 'lakehouse' 6 | 7 | model-paths: ["tmp/snow"] 8 | analysis-paths: ["analyses"] 9 | test-paths: ["tests"] 10 | seed-paths: ["seeds"] 11 | macro-paths: ["macros"] 12 | snapshot-paths: ["snapshots"] 13 | 14 | -------------------------------------------------------------------------------- /docs/catalog.json: -------------------------------------------------------------------------------- 1 | {"metadata": {"dbt_schema_version": "https://schemas.getdbt.com/dbt/catalog/v1.json", "dbt_version": "1.5.3", "generated_at": "2023-07-26T21:00:46.896986Z", "invocation_id": "7853c388-a81d-45ae-8707-f466041ea976", "env": {}}, "nodes": {}, "sources": {}, "errors": null} -------------------------------------------------------------------------------- /helper/_resources/01-discovery.py: -------------------------------------------------------------------------------- 1 | # Databricks notebook source 2 | import os 3 | import re 4 | 5 | dbutils.widgets.text("repo_path", "/") 6 | dbutils.widgets.text("sourcedb", "snowflake") 7 | 8 | #Catalog and schema targets from your dbt project profile 9 | dbutils.widgets.text("catalog", "catalog") 10 | dbutils.widgets.text("schema", "schema") 11 | 12 | debugmode = dbutils.widgets.get("debugmode") 13 | parsemacro = dbutils.widgets.get("parsemacro") 14 | subdir = dbutils.widgets.get("subdir") 15 | subdirpath = dbutils.widgets.get("subdirpath") 16 | 17 | # COMMAND ---------- 18 | 19 | # MAGIC %md 20 | # MAGIC 21 | # MAGIC ## Helper Functions 22 | 23 | # COMMAND ---------- 24 | 25 | ## Function to discover sql files in a given Repo cloned to Databricks 26 | ## Add a check for whether in Databricks or external 27 | 28 | def get_dir_content(ls_path): 29 | dir_paths = dbutils.fs.ls(ls_path) 30 | subdir_paths = [get_dir_content(p.path) for p in dir_paths if p.isDir() and p.path != ls_path] 31 | flat_subdir_paths = [p for subdir in subdir_paths for p in subdir] 32 | return list(map(lambda p: p.path, dir_paths)) + flat_subdir_paths 33 | 34 | ## Function to convert Snowflake functions to dbt macros 35 | 36 | def function_to_macro(content, function_name): 37 | 38 | pattern = r'({}\()([^)]*)\)'.format(function_name) #Look for functions of the format name(input1,input2) 39 | replacement_doubleQuotes = r'{{lakehouse_utils.\1"\2")}}' #Surround the expression with double curly braces, and quotes on either end 40 | 41 | check_preventDoubleReplace_pattern = r'({{lakehouse_utils.{}\()([^)]*)\)'.format(function_name) 42 | check_preventInnerReplace_pattern = r'(\w{}\()([^)]*)\)'.format(function_name) 43 | 44 | # If the function hasn't already been replaced with a macro AND isn't a subpart of another function name, then continue 45 | if (re.search(check_preventDoubleReplace_pattern,content) is None) & (re.search(check_preventInnerReplace_pattern,content) is None): 46 | try: 47 | number_of_matches = len(re.findall(pattern, content)) 48 | except: 49 | number_of_matches = 0 50 | 51 | updated_content = re.sub(pattern, replacement_doubleQuotes, content) 52 | 53 | #print(updated_content) 54 | 55 | matched_patterns = re.findall(pattern,updated_content) 56 | 57 | #print(matched_patterns) 58 | 59 | for i in matched_patterns: 60 | 61 | # Substitute quotes around inner commas 62 | 63 | commas = r',' 64 | quoted_commas = r'","' 65 | updated_match = re.sub(commas,quoted_commas,i[1]) 66 | updated_content = updated_content.replace(i[1], updated_match) 67 | 68 | # If we inadvertently surrounded a double-quoted string with more double-quotes, change these to be single quotes to prevent compatibility issues! 69 | 70 | double_doubleQuotes_pattern = r'""([^"]*)""' 71 | single_doubleQuotes_pattern = r"""'"\1"'""" 72 | 73 | updated_content = re.sub(double_doubleQuotes_pattern,single_doubleQuotes_pattern,updated_content) 74 | 75 | # If we inadvertently added double-quotes to an empty input macro, remove these! 76 | 77 | accidental_doubleQuotes_pattern = r'({{lakehouse_utils.{}\()""\)'.format(function_name) 78 | fixed_noQuotes_pattern = r'\1)' 79 | 80 | updated_content = re.sub(accidental_doubleQuotes_pattern,fixed_noQuotes_pattern,updated_content) 81 | 82 | # If the previous check failed, continue unchanged 83 | else: 84 | updated_content = content 85 | number_of_matches = 0 86 | 87 | return (updated_content, number_of_matches) 88 | 89 | # COMMAND ---------- 90 | 91 | # MAGIC %md 92 | # MAGIC 93 | # MAGIC ## Define function for all .sql files in the dbt repo 94 | 95 | # COMMAND ---------- 96 | 97 | from concurrent.futures import ThreadPoolExecutor, as_completed, wait 98 | 99 | ## Function to asynchronously kick off: open each file, loop through every function, write results 100 | 101 | def process_file(full_path, functions_list): 102 | 103 | converted_functions = dict() 104 | with open(full_path, 'r+') as file: 105 | content = file.read() 106 | for function_name in functions_list: 107 | content, no_matches = function_to_macro(content, function_name) 108 | 109 | if no_matches > 0: 110 | converted_functions[function_name] = no_matches 111 | 112 | #file.seek(0) 113 | #file.write(content) 114 | #file.truncate() 115 | 116 | return (full_path, converted_functions) ## Return list of functions that converted 117 | 118 | def dbt_project_functions_to_macros(repo_path): 119 | # Verify we are running in a dbt project 120 | try: 121 | dbutils.fs.ls(f'file:/Workspace/Repos/{repo_path}/dbt_project.yml') 122 | 123 | print("Valid dbt project!") 124 | print("Converting .sql files in the Models folder...") 125 | 126 | paths = [] 127 | 128 | if subdir == 'true': 129 | paths = get_dir_content(f'file:/Workspace/Repos/{repo_path}/models/{subdirpath}') 130 | 131 | else: 132 | paths = get_dir_content(f'file:/Workspace/Repos/{repo_path}/models') 133 | 134 | # List all sql files to be checked in a folder 135 | if parsemacro == 'true': 136 | paths.append(get_dir_content(f'file:/Workspace/Repos/{repo_path}/macros')) 137 | 138 | sql_files = [i[5:] for i in paths if '.sql' in i] 139 | discovery_array = [] 140 | 141 | with ThreadPoolExecutor() as executor: 142 | futures_sql = {executor.submit(process_file, p, input_functions): p for p in sql_files} 143 | for future in as_completed(futures_sql): 144 | data = future.result() 145 | if data: 146 | print(f"Processed: {data[0]} Converted Functions: {data[1]}") 147 | 148 | else: 149 | print(f"Nothing to change: {data}") 150 | 151 | discovery_array.append(data[1]) 152 | 153 | 154 | return discovery_array 155 | except: 156 | print("Not a valid dbt project") 157 | 158 | # COMMAND ---------- 159 | 160 | # MAGIC %md 161 | # MAGIC 162 | # MAGIC ## List of unsupported snowflake functions 163 | 164 | # COMMAND ---------- 165 | 166 | catalog = dbutils.widgets.get("catalog") 167 | schema = dbutils.widgets.get("schema") 168 | sourcedb = dbutils.widgets.get("sourcedb") 169 | if sourcedb == 'snowflake': 170 | input_functionsql = sql('select * from {}.{}.blockedfunctionlist'.format(catalog, schema)) 171 | 172 | 173 | input_functionspd = input_functionsql.toPandas() 174 | input_functions = input_functionspd["function_name"] 175 | -------------------------------------------------------------------------------- /helper/_resources/config/redshift/dt_mappings.json: -------------------------------------------------------------------------------- 1 | { 2 | "VARCHAR": {"source_name": "VARCHAR", "target_name": "STRING"}, 3 | "CHARACTER": {"source_name": "CHARACTER", "target_name": "STRING"}, 4 | "CHAR": {"source_name": "CHAR", "target_name": "STRING"}, 5 | "TEXT": {"source_name": "TEXT", "target_name": "STRING"}, 6 | "BPCHAR": {"source_name": "BPCHAR", "target_name": "STRING"}, 7 | "NCHAR": {"source_name": "NCHAR", "target_name": "STRING"}, 8 | "NVARCHAR": {"source_name": "NVARCHAR", "target_name": "STRING"}, 9 | "VARBYTE": {"source_name": "VARBYTE", "target_name": "BINARY"}, 10 | "BINARY VARYING": {"source_name": "BINARY VARYING", "target_name": "BINARY"}, 11 | "VARBINARY": {"source_name": "VARBINARY", "target_name": "BINARY"}, 12 | "INT2": {"source_name": "INT2", "target_name": "SMALLINT"}, 13 | "INT4": {"source_name": "INT4", "target_name": "INT"}, 14 | "INT8": {"source_name": "INT8", "target_name": "BIGINT"}, 15 | "NUMBER": {"source_name": "NUMBER", "target_name": "NUMERIC"}, 16 | "BYTEINT": {"source_name": "BYTEINT", "target_name": "BYTE"}, 17 | "FLOAT4": {"source_name": "FLOAT4", "target_name": "FLOAT"}, 18 | "FLOAT8": {"source_name": "FLOAT8", "target_name": "DOUBLE"}, 19 | "DOUBLE PRECISION": {"source_name": "DOUBLE PRECISION", "target_name": "DOUBLE"}, 20 | "TIME WITHOUT TIME ZONE": {"source_name": "TIME WITHOUT TIME ZONE", "target_name": "TIMESTAMP"}, 21 | "TIME WITH TIME ZONE": {"source_name": "TIME WITH TIME ZONE", "target_name": "TIMESTAMP"}, 22 | "TIMESTAMP WITHOUT TIME ZONE": {"source_name": "TIMESTAMP WITHOUT TIME ZONE", "target_name": "TIMESTAMP"}, 23 | "TIMESTAMP WITH TIME ZONE": {"source_name": "TIMESTAMP WITH TIME ZONE", "target_name": "TIMESTAMP"}, 24 | "TIMESTAMPTZ": {"source_name": "TIMESTAMPTZ", "target_name": "TIMESTAMP"}, 25 | "TIMETZ": {"source_name": "TIMETZ", "target_name": "TIMESTAMP"}, 26 | "TIME": {"source_name": "TIME", "target_name": "TIMESTAMP"} 27 | } 28 | -------------------------------------------------------------------------------- /helper/_resources/config/redshift/function_mappings.json: -------------------------------------------------------------------------------- 1 | { 2 | "convert": {"source_name": "convert", "macro_name": "convert"}, 3 | "text_to_numeric_alt": {"source_name": "text_to_numeric_alt", "macro_name": "text_to_numeric_alt"}, 4 | "hll_combine_sketches": {"source_name": "hll_combine_sketches", "macro_name": "hll_combine_sketches"}, 5 | "hll_combine": {"source_name": "hll_combine", "macro_name": "hll_combine"}, 6 | "hll_create_sketch": {"source_name": "hll_create_sketch", "macro_name": "hll_create_sketch"}, 7 | "hll_cardinality": {"source_name": "hll_cardinality", "macro_name": "hll_cardinality"}, 8 | "dexp": {"source_name": "dexp", "macro_name": "dexp"}, 9 | "dlog10": {"source_name": "dlog10", "macro_name": "dlog10"}, 10 | "dlog1": {"source_name": "dlog1", "macro_name": "dlog1"}, 11 | "getdate": {"source_name": "getdate", "macro_name": "redshift_getdate"}, 12 | "strtol": {"source_name": "strtol", "macro_name": "strtol"}, 13 | "isnull": {"source_name": "isnull", "macro_name": "isnull"}, 14 | "sysdate": {"source_name": "sysdate", "macro_name": "redshift_sysdate"}, 15 | "datediff": {"source_name": "datediff", "macro_name": "datediff"}, 16 | "date_trunc": {"source_name": "date_trunc", "macro_name": "date_trunc"}, 17 | "date_part": {"source_name": "date_part", "macro_name": "date_part"} 18 | } -------------------------------------------------------------------------------- /helper/_resources/config/redshift/functionlist.csv: -------------------------------------------------------------------------------- 1 | function_name 2 | convert 3 | text_to_numeric_alt 4 | hll_combine_sketches 5 | hll_combine 6 | hll_create_sketch 7 | hll_cardinality 8 | dexp 9 | dlog10 10 | dlog1 11 | getdate 12 | strtol 13 | isnull 14 | sysdate 15 | datediff 16 | date_trunc 17 | date_part -------------------------------------------------------------------------------- /helper/_resources/config/snowflake/blockedfunctionlist.csv: -------------------------------------------------------------------------------- 1 | function_name,udf 2 | convert_timezone,"CREATE OR REPLACE FUNCTION convert_timezone(source STRING, target STRING, stamp TIMESTAMP) 3 | RETURNS TIMESTAMP 4 | RETURN from_utc_timestamp(to_utc_timestamp(stamp, source), target);" 5 | to_varchar,"CREATE OR REPLACE FUNCTION to_varchar(arg DOUBLE) 6 | RETURNS STRING 7 | RETURN CAST(arg AS STRING);" 8 | parse_json,"(string) from_json(string, schema_of_json(string)) -- not supproted, we dont support variants-- would string be sufficient if they just want to query semi-structured data?" 9 | to_char,"CREATE OR REPLACE FUNCTION to_char(arg DOUBLE) 10 | RETURNS STRING 11 | RETURN CAST(arg AS STRING);" 12 | last_query_id,no databricks equivalent 13 | array_construct, 14 | object_construct,how do we make this kwargs? RS TODO 15 | is_null_value,(string) isnull(string) 16 | current_transaction,no databricks equivalent 17 | object_insert,no databricks equivalent 18 | check_json,no databricks equivalent 19 | hll_export,no databricks equivalent 20 | decrypt,no databricks equivalent 21 | get,not supported 22 | current_region,no equivalent 23 | get_ddl,further research needed 24 | try_parse_json,no equivalent 25 | to_geography,no equivalent 26 | parse_xml,no equivalent 27 | object_delete,no equivalent 28 | standardize,unable to find? 29 | hll_estimate,no equivalent 30 | get_path, 31 | st_intersects, 32 | to_numeric,"(arg, expr, p, s) to_number(arg, expr, p, s)" 33 | try_to_date,no comparable databricks dql 34 | try_to_timestamp,no comparable databricks dql 35 | as_varchar,dbx does not recognize variant input 36 | as_char,dbx does not recognize variant input 37 | to_timestamp_ltz,when using to_timestamp databricks will apply the offset rather than persisting it. 38 | current_version,no databricks equivalent dql 39 | minhash_combine,no databricks equivalent dql 40 | truncate,no databricks equivalent dql 41 | try_to_boolean,no databricks equivalent dql 42 | try_to_timestamp_ntz,no databricks equivalent dql 43 | current_role,no databricks equivalent dql 44 | hll,HLL can take in any expression whereas cardinality only takes in array/map expressions 45 | approximate_similarity,no databricks equivalent dql 46 | objectagg,dbx does not support objects or variants 47 | ratio_to_report,no databricks equivalent dql 48 | is_role_in_session,no databricks equivalent dql 49 | time_slice,no databricks equivalent dql 50 | is_integer,no databricks equivalent dql 51 | unicode,no databricks equivalent dql 52 | to_variant,dbx does not support variant 53 | xmlget,no databricks equivalent dql 54 | try_to_time,no databricks equivalent dql 55 | is_real,no databricks equivalent dql 56 | minhash,no databricks equivalent dql 57 | current_warehouse,no databricks equivalent dql 58 | to_double,no databricks equivalent dql 59 | to_object,dbx does not support object 60 | md5_number_lower64,no databricks equivalent dql 61 | encrypt,"aes_encrypt use binary key, not varchar passphrase. encrypt_raw can probably be transpiled" 62 | object_keys,json_object_keys 63 | current_client,no databricks equivalent dql 64 | try_to_timestamp_tz,dbx does not support timestamp_tz 65 | compress,no databricks equivalent dql 66 | md5_number_upper64,no databricks equivalent dql 67 | is_date,no databricks equivalent dql 68 | array_construct_compact,no way to pass in kwargs to macro. we could ask to pass in a list but that would require a bit of manual intervention. 69 | as_integer,dbx does not support variant input 70 | enrich_placement_ad_type,no databricks equivalent dql 71 | approximate_jaccard_index,no databricks equivalent dql 72 | as_date,dbx does not support variant input 73 | md5_hex,no databricks equivalent dql 74 | randstr,no databricks equivalent dql 75 | hash_agg,no databricks equivalent dql 76 | hll_import,no databricks equivalent dql 77 | is_boolean,dbx does not take in variant args 78 | as_number,dbx does not take in variant args 79 | hex_decode_binary,no databricks equivalent dql 80 | last_transaction,no databricks equivalent dql 81 | sha2_binary,no databricks equivalent dql 82 | try_base64_decode_string,no databricks equivalent dql -------------------------------------------------------------------------------- /helper/_resources/config/snowflake/dt_mappings.json: -------------------------------------------------------------------------------- 1 | { 2 | "VARCHAR": {"source_name": "VARCHAR", "target_name": "STRING"}, 3 | "CHAR": {"source_name": "CHAR", "target_name": "STRING"}, 4 | "CHARACTER": {"source_name": "CHARACTER", "target_name": "STRING"}, 5 | "TEXT": {"source_name": "TEXT", "target_name": "STRING"}, 6 | "VARBINARY": {"source_name": "VARBINARY", "target_name": "BINARY"}, 7 | "NUMBER": {"source_name": "NUMBER", "target_name": "NUMERIC"}, 8 | "BYTEINT": {"source_name": "BYTEINT", "target_name": "BYTE"}, 9 | "FLOAT4": {"source_name": "FLOAT4", "target_name": "DOUBLE"}, 10 | "FLOAT8": {"source_name": "FLOAT8", "target_name": "DOUBLE"}, 11 | "FLOAT": {"source_name": "FLOAT", "target_name": "DOUBLE"}, 12 | "DOUBLE PRECISION": {"source_name": "DOUBLE PRECISION", "target_name": "DOUBLE"}, 13 | "REAL": {"source_name": "REAL", "target_name": "DOUBLE"}, 14 | "TIME": {"source_name": "TIME", "target_name": "TIMESTAMP"}, 15 | "DATETIME": {"source_name": "DATETIME", "target_name": "TIMESTAMP"}, 16 | "TIMESTAMP_LTZ": {"source_name": "TIMESTAMP_LTZ", "target_name": "TIMESTAMP"}, 17 | "TIMESTAMP_NTZ": {"source_name": "TIMESTAMP_NTZ", "target_name": "TIMESTAMP"}, 18 | "TIMESTAMP_TZ": {"source_name": "TIMESTAMP_TZ", "target_name": "TIMESTAMP"}, 19 | "OBJECT": {"source_name": "OBJECT", "target_name": "STRUCT"} 20 | } 21 | -------------------------------------------------------------------------------- /helper/_resources/config/snowflake/function_mappings.json: -------------------------------------------------------------------------------- 1 | { 2 | "md5_binary" : {"source_name": "md5_binary", "macro_name": "md5_binary"}, 3 | "json_extract_path": {"source_name": "json_extract_path", "macro_name": "json_extract_path"}, 4 | "base64_encode": {"source_name": "base64_encode", "macro_name": "base64_encode"}, 5 | "zeroifnull": {"source_name": "zeroifnull", "macro_name": "zeroifnull"}, 6 | "seq4": {"source_name": "seq4", "macro_name": "seq4"}, 7 | "strtok_to_array": {"source_name": "strtok_to_array", "macro_name": "strtok_to_array"}, 8 | "to_number": {"source_name": "to_number", "macro_name": "to_number"}, 9 | "array_size": {"source_name": "array_size", "macro_name": "array_size"}, 10 | "dayname": {"source_name": "dayname", "macro_name": "dayname"}, 11 | "timestampadd": {"source_name": "timestampadd", "macro_name": "timestampadd"}, 12 | "week": {"source_name": "week", "macro_name": "week"}, 13 | "date_from_parts": {"source_name": "date_from_parts", "macro_name": "date_from_parts"}, 14 | "monthname": {"source_name": "monthname", "macro_name": "monthname"}, 15 | "to_time": {"source_name": "to_time", "macro_name": "to_time"}, 16 | "try_to_number": {"source_name": "try_to_number", "macro_name": "try_to_number"}, 17 | "try_to_numeric": {"source_name": "try_to_numeric", "macro_name": "try_to_numeric"}, 18 | "to_decimal": {"source_name": "to_decimal", "macro_name": "to_decimal"}, 19 | "to_numeric": {"source_name": "to_numeric", "macro_name": "to_numeric"}, 20 | "try_to_decimal": {"source_name": "try_to_decimal", "macro_name": "try_to_decimal"}, 21 | "to_boolean": {"source_name": "to_boolean", "macro_name": "to_boolean"}, 22 | "to_array": {"source_name": "to_array", "macro_name": "to_array"}, 23 | "listagg": {"source_name": "listagg", "macro_name": "listagg"}, 24 | "array_to_string": {"source_name": "array_to_string", "macro_name": "array_to_string"}, 25 | "hll_estimate": {"source_name": "hll_estimate", "macro_name": "hll_estimate"}, 26 | "uniform": {"source_name": "uniform", "macro_name": "uniform"}, 27 | "div0": {"source_name": "div0", "macro_name": "div0"}, 28 | "square": {"source_name": "square", "macro_name": "square"}, 29 | "uuid_string": {"source_name": "uuid_string", "macro_name": "uuid_string"}, 30 | "time": {"source_name": "time", "macro_name": "time"}, 31 | "previous_day": {"source_name": "previous_day", "macro_name": "previous_day"}, 32 | "array_intersection": {"source_name": "array_intersection", "macro_name": "array_intersection"}, 33 | "sysdate": {"source_name": "sysdate", "macro_name": "sysdate"}, 34 | "sha2_hex": {"source_name": "sha2_hex", "macro_name": "sha2_hex"}, 35 | "dayofweekiso": {"source_name": "dayofweekiso", "macro_name": "dayofweekiso"}, 36 | "nullifzero": {"source_name": "nullifzero", "macro_name": "nullifzero"}, 37 | "array_cat": {"source_name": "array_cat", "macro_name": "array_cat"}, 38 | "seq8": {"source_name": "seq8", "macro_name": "seq8"}, 39 | "timestamp_from_parts": {"source_name": "timestamp_from_parts", "macro_name": "timestamp_from_parts"}, 40 | "weekiso": {"source_name": "weekiso", "macro_name": "weekiso"}, 41 | "boolor_agg": {"source_name": "boolor_agg", "macro_name": "boolor_agg"}, 42 | "yearofweekiso": {"source_name": "yearofweekiso", "macro_name": "yearofweekiso"}, 43 | "insert": {"source_name": "insert", "macro_name": "insert"}, 44 | "array_slice": {"source_name": "array_slice", "macro_name": "array_slice"}, 45 | "bitand": {"source_name": "bitand", "macro_name": "bitand"}, 46 | "timestamp_ntz_from_parts": {"source_name": "timestamp_ntz_from_parts", "macro_name": "timestamp_ntz_from_parts"}, 47 | "base64_decode_string": {"source_name": "base64_decode_string", "macro_name": "base64_decode_string"}, 48 | "systimestamp": {"source_name": "systimestamp", "macro_name": "systimestamp"}, 49 | "hex_decode_string": {"source_name": "hex_decode_string", "macro_name": "hex_decode_string"}, 50 | "variance_samp": {"source_name": "variance_samp", "macro_name": "variance_samp"}, 51 | "seq2": {"source_name": "seq2", "macro_name": "seq2"}, 52 | "base64_decode_binary": {"source_name": "base64_decode_binary", "macro_name": "base64_decode_binary"}, 53 | "booland_agg": {"source_name": "booland_agg", "macro_name": "booland_agg"}, 54 | "seq1": {"source_name": "seq1", "macro_name": "seq1"}, 55 | "yearofweek": {"source_name": "yearofweek", "macro_name": "yearofweek"}, 56 | "sha1_hex": {"source_name": "sha1_hex", "macro_name": "sha1_hex"}, 57 | "strtok": {"source_name": "strtok", "macro_name": "strtok"} 58 | } 59 | -------------------------------------------------------------------------------- /helper/_resources/config/snowflake/functionlist.csv: -------------------------------------------------------------------------------- 1 | function_name 2 | md5_binary 3 | json_extract_path 4 | base64_encode 5 | zeroifnull 6 | seq4 7 | strtok_to_array 8 | to_number 9 | array_size 10 | dateadd 11 | dayname 12 | timestampadd 13 | week 14 | timediff 15 | date_from_parts 16 | monthname 17 | timestampdiff 18 | to_time 19 | timeadd 20 | try_to_number 21 | try_to_numeric 22 | to_decimal 23 | to_numeric 24 | try_to_decimal 25 | to_boolean 26 | to_array 27 | listagg 28 | array_to_string 29 | hll_estimate 30 | uniform 31 | div0 32 | square 33 | uuid_string 34 | time 35 | previous_day 36 | array_intersection 37 | sysdate 38 | sha2_hex 39 | dayofweekiso 40 | nullifzero 41 | array_cat 42 | seq8 43 | timestamp_from_parts 44 | weekiso 45 | boolor_agg 46 | yearofweekiso 47 | insert 48 | array_slice 49 | bitand 50 | timestamp_ntz_from_parts 51 | base64_decode_string 52 | systimestamp 53 | hex_decode_string 54 | variance_samp 55 | seq2 56 | base64_decode_binary 57 | booland_agg 58 | seq1 59 | yearofweek 60 | sha1_hex 61 | strtok 62 | -------------------------------------------------------------------------------- /helper/_resources/config/snowflake/springbrickstests.csv: -------------------------------------------------------------------------------- 1 | function_name,input,expected_output 2 | any_value,, 3 | approx_top_k,, 4 | approximate_count_distinct,, 5 | approximate_jaccard_index,, 6 | approximate_similarity,, 7 | array_agg,coffee,"coffee, iced tea, latte, tea" 8 | array_agg,iced tea,"coffee, iced tea, latte, tea" 9 | array_agg,latte,"coffee, iced tea, latte, tea" 10 | array_agg,tea,"coffee, iced tea, latte, tea" 11 | array_append,, 12 | array_cat,"coffee, iced tea","coffee, iced tea, latte, tea" 13 | array_cat,"latte,tea","coffee, iced tea, latte, tea" 14 | array_compact,, 15 | array_construct,, 16 | array_construct_compact,, 17 | array_insert,, 18 | array_intersection,, 19 | array_size,, 20 | array_slice,, 21 | array_to_string,, 22 | arrayagg,, 23 | as_char,, 24 | as_date,, 25 | as_integer,, 26 | as_number,, 27 | as_varchar,, 28 | base64_decode_binary,, 29 | base64_decode_string,, 30 | base64_encode,, 31 | bitand,, 32 | booland_agg,, 33 | boolor_agg,, 34 | boolxor_agg,, 35 | charindex,, 36 | check_json,, 37 | compress,, 38 | contains,coffee,FALSE 39 | contains,iced tea,TRUE 40 | contains,latte,TRUE 41 | contains,tea,TRUE 42 | contains,NULL,NULL 43 | control.harmonize_compact,, 44 | convert_timezone,, 45 | date_from_parts,"{""col1"":""2023"",""col2"":""01"",""col3"":""10""}",10/1/2023 46 | dateadd,"{""col1"":""day"",""col2"":""7"",""col3"":""2023-01-10""}",17/1/2023 47 | dateadd,"{""col1"":""minute"",""col2"":""11"",""col3"":""2023-01-10 7:13""}",10/1/2023 7:24 48 | dayname,3/5/2023,Wed 49 | dayname,8/5/2023 11:15,Mon 50 | dayofweekiso,3/5/2023,3 51 | dayofweekiso,8/5/2023 11:15,1 52 | decrypt,, 53 | div0,, 54 | editdistance,, 55 | encrypt,, 56 | endswith,, 57 | enrich_placement_ad_type,, 58 | equal_null,, 59 | get,, 60 | get_ddl,, 61 | get_path,, 62 | getdate,, 63 | hash_agg,, 64 | hex_decode_binary,, 65 | hex_decode_string,, 66 | hll,, 67 | hll_estimate,, 68 | hll_export,, 69 | hll_import,, 70 | iff,, 71 | ilike,, 72 | insert,, 73 | is_boolean,, 74 | is_date,, 75 | is_integer,, 76 | is_null_value,, 77 | is_real,, 78 | is_role_in_session,, 79 | json_extract_path_text,, 80 | last_query_id,, 81 | last_transaction,, 82 | len,, 83 | listagg,, 84 | md5_binary,Snowflake,EDF1439075A83A447FB8B630DDC9C8DE 85 | md5_hex,, 86 | md5_number_lower64,, 87 | md5_number_upper64,, 88 | median,, 89 | minhash,, 90 | minhash_combine,, 91 | mode,, 92 | monthname,1/5/2015,May 93 | monthname,3/4/2015 10:00,Apr 94 | nullifzero,, 95 | object_agg,, 96 | object_construct,, 97 | object_delete,, 98 | object_insert,, 99 | object_keys,, 100 | objectagg,, 101 | parse_json,, 102 | parse_xml,, 103 | percentile_cont,, 104 | percentile_disc,, 105 | previous_day,, 106 | randstr,, 107 | ratio_to_report,, 108 | regexp,, 109 | regexp_count,, 110 | regexp_instr,, 111 | regexp_like,, 112 | regexp_substr,, 113 | seq1,, 114 | seq2,, 115 | seq4,, 116 | seq8,, 117 | sha1_hex,, 118 | sha2_binary,, 119 | sha2_hex,, 120 | split_part,"{11.22.33, ""."", 0}",11 121 | split_part,"{11.22.33, ""."", 1}",11 122 | split_part,"{11.22.33, ""."", 2}",22 123 | split_part,"{11.22.33, ""."", 3}",33 124 | split_part,"{11.22.33, ""."", 4}", 125 | split_part,"{11.22.33, ""."", -1}",33 126 | split_part,"{11.22.33, ""."", -2}",22 127 | split_part,"{11.22.33, ""."", -3}",11 128 | split_part,"{11.22.33, ""."", -4}", 129 | square,, 130 | st_intersects,, 131 | standardize,, 132 | startswith,coffee,FALSE 133 | startswith,iced tea,FALSE 134 | startswith,latte,FALSE 135 | startswith,tea,TRUE 136 | startswith,NULL,NULL 137 | strtok,, 138 | strtok_to_array,"{""col1:""a.b.c"",""col2"", "".""}","[""a"", ""b"", ""c""]" 139 | strtok_to_array,"{""col1"":""user@snowflake.com"", ""col2"":"".@""}","[""user"",""snowflake"",""com""]" 140 | sysdate,, 141 | systimestamp,, 142 | time,, 143 | time_slice,, 144 | timeadd,"{""col1"":""year"", ""col2"":2, ""col3"":""2013-05-08""}","""2015-05-08""" 145 | timeadd,"{""col1"":""hour"", ""col2"":2, ""col3"": ""2013-04-05 02:00:00.000""}","""2015-05-08""" 146 | timediff,"{""col1"":""year"", ""col2"":""2017-01-01"",""col3"":""2019-01-01""}",2 147 | timediff,"{""col1"":""month"", ""col2"":""2017-01-01"", ""col3"":""2017-12-31""}",11 148 | timestamp_from_parts,, 149 | timestamp_ntz_from_parts,, 150 | timestampadd,"{""col1"":year"", ""col2"": 2, ""col3"":""2013-05-08""}","""2015-05-08""" 151 | timestampadd,"{""col1"":""hour"", ""col2"":2, ""col3"":""2013-04-05 00:00:00.000""}","""2013-04-05 02:00:00""" 152 | timestampdiff,"{""col1"":""year"",""col2"": ""2017-01-01"",""col3"": ""2019-01-01""}",2 153 | timestampdiff,"{""col1"":""month"", ""col2"":""2017-01-01"",""col3"": ""2017-12-31""}",11 154 | to_array,1,[1] 155 | to_array,3,[3] 156 | to_binary,"(""col1"": ""SNOW"", ""col2"":utf-8"")",534E4F57 157 | to_boolean,yes,TRUE 158 | to_boolean,no,FALSE 159 | to_boolean,NULL,NULL 160 | to_boolean,1,TRUE 161 | to_boolean,0,FALSE 162 | to_boolean,NULL,NULL 163 | to_char,"{""col1"":'2013-04-05 01:02:03', ""col2"":'mm/dd/yyyy', ""col3"":'hh23:mi hours'}","{""col1"":'04/05/2013', ""col2"":'01:02 hours'}" 164 | to_char,"{""col1"":""03-May-2013""}",3/5/2013 165 | to_char,"{""col1"":""03-May-2013"", ""col2"":""yyyy.mm.dd""}",2013.05.03 166 | to_number,12.3456,12 167 | to_number,98.76546,99 168 | to_number,"{12.3456, 10, 1}",12.3 169 | to_number,"{98.76546, 10, 1}",98.8 170 | to_number,"{12.3456, 10, 8}",12.3456 171 | to_number,"{98.76546, 10, 8}",98.7645 172 | to_double,, 173 | to_geography,, 174 | to_decimal,1, 175 | to_decimal,-12.3, 176 | to_decimal,0, 177 | to_decimal,-0.1, 178 | to_decimal,"{1, '99.9', 9, 5}",1.00000' 179 | to_decimal,"{-12.3, '99.9', 9, 5}",-12.30000' 180 | to_decimal,"{0.0, '99.9', 9, 5}",0.00000' 181 | to_decimal,"{-0.1, '99.9', 9, 5}",-0.10000' 182 | to_decimal,"{1, 'TM9', 9, 5}",1.00000' 183 | to_decimal,"{1, 'TM9', 9, 5}",-12.30000' 184 | to_decimal,"{1, 'TM9', 9, 5}",0.00000' 185 | to_decimal,"{1, 'TM9', 9, 5}",-0.10000' 186 | to_numeric,12.3456,12 187 | to_numeric,98.76546,99 188 | to_numeric,"{12.3456, 10, 1}",12.3 189 | to_numeric,"{98.76546, 10, 1}",98.8 190 | to_numeric,"{12.3456, 10, 8}",12.3456 191 | to_numeric,"{98.76546, 10, 8}",98.7645 192 | to_object,, 193 | to_time,"{""col"":'13:30:00'}",13:30:00' 194 | to_time,"{""col1"":'11.15.00', '""col2"":'HH24.MI.SS'}",11:15:00' 195 | to_timestamp_ltz,, 196 | to_timestamp_ntz,todo, 197 | to_timestamp_tz,todo, 198 | to_varchar,"{""col1"":'2013-04-05 01:02:03', ""col2"":'mm/dd/yyyy, hh24:mi hours'}","{'04/05/2013', '01:02 hours'}" 199 | to_varchar,"{""03-May-2013""}",3/5/2013 200 | to_varchar,"{""col1"":""03-May-2013"", ""col2"":""yyyy.mm.dd""}",2013.05.03 201 | to_variant,, 202 | truncate,, 203 | try_base64_decode_string,, 204 | try_cast,"{""col1"":'05-Mar-2016',""col2"": 'AS TIMESTAMP'}",2016-03-05 00:00:00:000 205 | try_cast,"{""col1"":'05/2016', ""col2"":'AS TIMESTAMP'}",NULL 206 | try_cast,"{""col1"":'ABCD', ""col2"":'AS CHAR(2)'}",NULL 207 | try_cast,"{""col1"":'ABCD',""col2"": 'AS VARCHAR(10)'}",ABCD 208 | try_parse_json,, 209 | try_to_binary,, 210 | try_to_boolean,, 211 | try_to_date,, 212 | try_to_decimal,345.123,345 213 | try_to_decimal,"{345.123, 10, 2}",345.12 214 | try_to_decimal,"{345.123, 4, 2}",NULL 215 | try_to_decimal,"{'$345.12', '$999.00'}",345 216 | try_to_decimal,"{'$345.12', '$999.00', 5, 2}",345.12 217 | try_to_decimal,"{'$345.12', 5, 2}",NULL 218 | try_to_number,345.123,345 219 | try_to_number,"{345.123, 10, 2}",345.12 220 | try_to_number,"{345.123, 4, 2}",NULL 221 | try_to_number,"{'$345.12', '$999.00'}",345 222 | try_to_number,"{'$345.12', '$999.00', 5, 2}",345.12 223 | try_to_number,"{'$345.12', 5, 2}",NULL 224 | try_to_numeric,345.123,345 225 | try_to_numeric,"{345.123, 10, 2}",345.12 226 | try_to_numeric,"{345.123, 4, 2}",NULL 227 | try_to_numeric,"{'$345.12', '$999.00'}",345 228 | try_to_numeric,"{'$345.12', '$999.00', 5, 2}",345.12 229 | try_to_numeric,"{'$345.12', 5, 2}",NULL 230 | try_to_time,, 231 | try_to_timestamp,, 232 | try_to_timestamp_ntz,, 233 | try_to_timestamp_tz,, 234 | unicode,, 235 | uniform,, 236 | uuid_string,, 237 | variance_samp,, 238 | week,2016-01-02 23:39:20.123',53 239 | weekiso,, 240 | xmlget,, 241 | yearofweek,, 242 | yearofweekiso,, 243 | zeroifnull,1,1 244 | zeroifnull,NULL,0 245 | zeroifnull,5,5 246 | zeroifnull,0,0 247 | zeroifnull,3.14159,3.14159 -------------------------------------------------------------------------------- /helper/function_to_macro_discovery.py: -------------------------------------------------------------------------------- 1 | # Databricks notebook source 2 | # MAGIC %md 3 | # MAGIC 4 | # MAGIC ## Instructions 5 | # MAGIC 6 | # MAGIC 0. Pre-requisites: 7 | # MAGIC * Clone the target dbt project repo into Databricks and create a new branch 8 | # MAGIC * Run `dbt seed` in your IDE / dbt Cloud to ensure the list of functions to be replaced is populated 9 | # MAGIC 10 | # MAGIC 1. Attach a single-user UC cluster to the notebook (this will avoid compatibility issues when we can leverage the Helper Functions) 11 | # MAGIC 12 | # MAGIC 2. Populate the widgets with: 13 | # MAGIC 14 | # MAGIC - **Repo path:** Enter the path of the cloned repo here: e.g. `/` 15 | # MAGIC - **Targetdb:** Whether we are replacing snowflake or redshift functions 16 | # MAGIC - **Catalog:** The catalog you configured in your target dbt project. The `dbt seed` command will generate a list of functions to replace in this catalog 17 | # MAGIC - **Schema:** The schema you configured in your target dbt project. The `dbt seed` command will generate a list of functions to replace in this schema 18 | # MAGIC 19 | # MAGIC 3. Hit *Run all* in the top right of the notebook 20 | # MAGIC 21 | # MAGIC 4. Confirm 22 | # MAGIC 23 | # MAGIC ## What is this doing? 24 | # MAGIC 25 | # MAGIC 26 | # MAGIC - Verify the target is a valid dbt repo, e.g. search for a `dbt_project.yml` 27 | # MAGIC - For all .sql files in the Models folder, search for the existence of the fixed list of Snowflake / Redshift functions 28 | # MAGIC - For each function: 29 | # MAGIC - Verify it hasn't already been converted into a macro, e.g. ensure it isn't already preceded by `{{lakehouse_utils.` 30 | # MAGIC - Verify the function we are replacing isn't actually a substring of another function, e.g. `xmlget()` not `get()` 31 | # MAGIC - Replace the pattern `function_name(var1,var2,...)` with `{{lakehouse_utils.function_name("var1","var2",...)}}` 32 | 33 | # COMMAND ---------- 34 | 35 | dbutils.widgets.text("repo_path", "/") 36 | dbutils.widgets.dropdown("sourcedb", "snowflake", ["snowflake", "redshift"]) 37 | 38 | #Catalog and schema targets from your dbt project profile 39 | dbutils.widgets.text("catalog", "catalog") 40 | dbutils.widgets.text("schema", "schema") 41 | dbutils.widgets.dropdown("debugmode", "false", ["true", "false"]) 42 | dbutils.widgets.dropdown("parsemacro", "false", ["true", "false"]) 43 | dbutils.widgets.dropdown("subdir", "false", ["true", "false"]) 44 | dbutils.widgets.text("subdirpath", "redshift") 45 | 46 | 47 | # COMMAND ---------- 48 | 49 | # MAGIC %md 50 | # MAGIC 51 | # MAGIC ## Setup the discovery function 52 | 53 | # COMMAND ---------- 54 | 55 | # MAGIC %run ./_resources/01-discovery $sourcedb=$sourcedb $catalog=$catalog $schema=$schema $debugmode=$debugmode $parsemacro=$parsemacro $subdir=$subdir $subdirpath=$subdirpath 56 | 57 | # COMMAND ---------- 58 | 59 | # MAGIC %md 60 | # MAGIC 61 | # MAGIC ## Run the converter 62 | # MAGIC 63 | # MAGIC Enter your repo path as shown in the Databricks UI. e.g. `/` 64 | 65 | # COMMAND ---------- 66 | 67 | repo_path = dbutils.widgets.get("repo_path") 68 | 69 | listofdicts = dbt_project_functions_to_macros(repo_path) 70 | 71 | # COMMAND ---------- 72 | 73 | ###convert to df, pivot df, sum pivotcol, multipl *.5, 74 | import pandas as pd 75 | df= pd.DataFrame(listofdicts) 76 | meltdf = df.melt() 77 | sumseries = meltdf["value"].sum() 78 | totaleffort = sumseries / 2 79 | print(f"Approximate Total effort: {totaleffort} hours") 80 | 81 | # COMMAND ---------- 82 | 83 | if debugmode == 'true': 84 | if sourcedb == 'snowflake': 85 | if subdir == 'true' and subdirpath == "snow": 86 | assert totaleffort == 2.0 87 | print('testpass, woohoo') 88 | elif subdir == 'false' and parsemacro == 'false': 89 | assert totaleffort == 2.0 90 | print('testpass, woohoo') 91 | else: 92 | cow = 'moo' 93 | print('no tests validate this time around!') 94 | -------------------------------------------------------------------------------- /helper/pierunner.py.py: -------------------------------------------------------------------------------- 1 | # Databricks notebook source 2 | # MAGIC %sh 3 | # MAGIC python3 ./convert_to_databricks.py --sourcedb "redshift" --dir_path "redshift/" --parse_mode 'functions' --parse_first 'functions' --customdp 'true' --onlypublishagg "true" 4 | 5 | # COMMAND ---------- 6 | 7 | # MAGIC %sh 8 | # MAGIC python3 ./convert_to_databricks.py --sourcedb "snowflake" --dir_path "snowflake/" --parse_mode 'functions' --onlypublishagg "true" 9 | 10 | # COMMAND ---------- 11 | 12 | # MAGIC %sh 13 | # MAGIC python3 ./convert_to_databricks.py --sourcedb "redshift" --dir_path "redshift/" --parse_mode 'syntax' --parse_first 'syntax' 14 | 15 | # COMMAND ---------- 16 | 17 | # MAGIC %sh 18 | # MAGIC python3 ./convert_to_databricks.py --sourcedb "snowflake" --dir_path "snowflake/" --parse_mode 'syntax' --parse_first 'syntax' --onlypublishagg "true" 19 | 20 | # COMMAND ---------- 21 | 22 | # MAGIC %sh 23 | # MAGIC python3 ./convert_to_databricks.py --sourcedb "redshift" --dir_path "redshift/" --parse_mode 'syntax' --parse_first 'syntax' --customdp "true" --onlypublishagg "true" --tmplogs 'true' 24 | 25 | # COMMAND ---------- 26 | 27 | # MAGIC %sh 28 | # MAGIC python3 ./convert_to_databricks.py --sourcedb "redshift" --dir_path "redshift/" --parse_mode 'syntax' --customdp "true" 29 | 30 | # COMMAND ---------- 31 | 32 | # MAGIC %sh 33 | # MAGIC python3 ./convert_to_databricks.py --sourcedb "snowflake" --dir_path "snowflake/" --parse_mode 'syntax' --customdp "true" 34 | 35 | # COMMAND ---------- 36 | 37 | # MAGIC %sh 38 | # MAGIC python3 ./convert_to_databricks.py --sourcedb "redshift" --dir_path "redshift/" --parse_mode 'syntax' --customdp "true" 39 | 40 | # COMMAND ---------- 41 | 42 | # MAGIC %sh 43 | # MAGIC python3 ./convert_to_databricks.py --sourcedb "redshift" --dir_path "redshift/" --parse_mode 'discovery' --parse_first 'syntax' --customdp "true" 44 | 45 | # COMMAND ---------- 46 | 47 | # MAGIC %sh 48 | # MAGIC python3 ./convert_to_databricks.py --sourcedb "snowflake" --dir_path "snowflake/" --parse_mode 'discovery' --onlypublishagg 'true' 49 | 50 | # COMMAND ---------- 51 | 52 | # MAGIC %sh 53 | # MAGIC python3 ./convert_to_databricks.py --sourcedb "redshift" --dir_path "/Workspace/Repos/roberto.salcido@databricks.com/lakehouse_utils/tmp/beyondsqltest/testpyfiles" --parse_mode 'syntax' --parse_first 'syntax' --dir_mode 'nondbt' --file_type 'py' --except_list 'uno.py','dos.py' 54 | 55 | # COMMAND ---------- 56 | 57 | # MAGIC %sh 58 | # MAGIC python3 ./convert_to_databricks.py --sourcedb "redshift" --dir_path "/Workspace/Repos/roberto.salcido@databricks.com/lakehouse_utils/tmp/beyondsqltest/testlookmlfiles" --parse_mode 'syntax' --parse_first 'syntax' --dir_mode 'lookml' --file_type 'lkml' --except_list 'dos.lkml','tres.lkml' 59 | 60 | # COMMAND ---------- 61 | 62 | from pathlib import Path 63 | 64 | dirpath = "/Workspace/Repos/roberto.salcido@databricks.com/lakehouse_utils/models" 65 | path = Path(dirpath) 66 | print(f"Path to glob: {path}") 67 | globs = path.rglob('*.sql') 68 | for file in globs: 69 | print(file) 70 | 71 | # COMMAND ---------- 72 | 73 | 74 | -------------------------------------------------------------------------------- /integration_tests/dbt_project.yml: -------------------------------------------------------------------------------- 1 | name: 'springbricks_integration_tests' 2 | version: '1.0.0' 3 | config-version: 2 4 | 5 | profile: 'integration_tests' 6 | 7 | model-paths: ["models"] 8 | analysis-paths: ["analyses"] 9 | test-paths: ["tests"] 10 | seed-paths: ["seeds"] 11 | macro-paths: ["macros"] 12 | snapshot-paths: ["snapshots"] 13 | 14 | target-path: "target" 15 | clean-targets: 16 | - "target" 17 | - "dbt_packages" 18 | 19 | vars: 20 | max_ship_date: "'1998-12-01'" 21 | 22 | dispatch: 23 | - macro_namespace: dbt_utils 24 | search_order: ['dbsql_dbt_tpch', 'dbt_utils'] 25 | -------------------------------------------------------------------------------- /integration_tests/functionak.sql: -------------------------------------------------------------------------------- 1 | 2 | {{ 3 | config( 4 | materialized = 'table' 5 | ) 6 | }} 7 | 8 | select 9 | {{lakehouse_utils.convert('string','c_custkey')}} as stringkey, 10 | c_name, 11 | c_address, 12 | c_nationkey, 13 | c_phone, 14 | {{lakehouse_utils.dlog10('c_acctbal')}} as actbalbaseten, 15 | {{lakehouse_utils.dlog10('c_acctbal')}} as actbalbaseten, 16 | JSON_EXTRACT_PATH_TEXT('{"f2":{"f3":1},"f4":{"f5":99,"f6":"star"}}','f4', 'f6'), 17 | {{lakehouse_utils.dexp('100')}}, 18 | {{lakehouse_utils.date_part('dow',' 2008-01-05 14:00:00')}}, 19 | {{lakehouse_utils.hll_cardinality('expr')}}, 20 | JSON_ARRAY_LENGTH('[11,12,13,{"f1":21,"f2":[25,26]},14]'), 21 | c_mktsegment, 22 | c_comment, 23 | {{lakehouse_utils.getdate('')}} as hoy, 24 | GETDATE AS get_date_caps_test, 25 | {{lakehouse_utils.sysdate('')}} AS sys_date_col_test, 26 | {{lakehouse_utils.SYSDATE('')}} AS sys_date_caps_col_test, 27 | {{lakehouse_utils.ISNULL('test',' test_is_null')}} AS null_test_col_caps, 28 | {{lakehouse_utils.ISNULL('test',' test_is_null')}} AS null_test_col_caps, 29 | {{lakehouse_utils.isnull("test"," 'test_is_null'")}} AS null_test_col, 30 | {{lakehouse_utils.date_part('year',' date(origination_date)')}} || '-' || 'Q' || floor( 31 | ({{lakehouse_utils.date_part('month',' date(origination_date)')}} - 1) / 3) + 1 as origination_quarter, 32 | {{lakehouse_utils.date_part("SECONDS"," '2019-10-01 00:00:01.000001'::timestamp")}} 33 | first_value( 34 | case when colA = 2 then id2 35 | end ignore nulls 36 | ) over ( 37 | partition by 38 | customer_id 39 | order by 40 | created_at 41 | rows between unbounded preceding and unbounded following 42 | ) as test_syntax_change 43 | from 44 | redshift_sample_data.tpch_rs1.customer 45 | ORDER BY colC,colB DESC 46 | -------------------------------------------------------------------------------- /integration_tests/macros/array_agg.sql: -------------------------------------------------------------------------------- 1 | {% macro array_agg(arg, delim) %} 2 | CASE WHEN locate('distinct', lower({{arg}})) = 0 3 | THEN sort_array(collect_list({{arg}}), {{delim}}) 4 | ELSE sort_array(collect_list(DISTINCT {{arg}}), {{delim}}) 5 | END 6 | {% endmacro %} 7 | -------------------------------------------------------------------------------- /integration_tests/macros/array_cat.sql: -------------------------------------------------------------------------------- 1 | {% macro array_cat(arg1, arg2) %} 2 | concat({{arg1}}. {{arg2}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/array_compact.sql: -------------------------------------------------------------------------------- 1 | {% macro array_compact(arg) %} 2 | filter({{arg}} , x -> x IS NOT NULL) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/array_construct.sql: -------------------------------------------------------------------------------- 1 | {% macro array_construct(expr) %} 2 | array({{expr}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/array_intersection.sql: -------------------------------------------------------------------------------- 1 | {% macro array_intersection(arg1, arg2) %} 2 | array_intersect({{arg1}}, {{arg2}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/array_size.sql: -------------------------------------------------------------------------------- 1 | {% macro array_size(column_name) %} 2 | size({{column_name}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/array_to_string.sql: -------------------------------------------------------------------------------- 1 | {% macro array_to_string(arg, delim) %} 2 | array_join({{arg}}, {{delim}}, null) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/base64_decode_binary.sql: -------------------------------------------------------------------------------- 1 | {% macro base64_decode_binary(arg) %} 2 | unbase64({{arg}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/base64_decode_string.sql: -------------------------------------------------------------------------------- 1 | {% macro base64_decode_string(arg) %} 2 | unbase({{arg}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/base64_encode.sql: -------------------------------------------------------------------------------- 1 | {% macro base64_encode(arg) %} 2 | base64({{arg}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/bitand.sql: -------------------------------------------------------------------------------- 1 | {% macro bitand(arg1, arg2) %} 2 | {{arg1}} & {{arg2}} 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/charindex.sql: -------------------------------------------------------------------------------- 1 | {% macro charindex(arg1, arg2, start) %} 2 | position({{arg1}}, {{arg2}}, {{start}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/contains.sql: -------------------------------------------------------------------------------- 1 | {% macro contains(column_name, position) %} 2 | 3 | charindex({{position}}, {{column_name}}) > 0 4 | 5 | {% endmacro %} 6 | -------------------------------------------------------------------------------- /integration_tests/macros/current_schema.sql: -------------------------------------------------------------------------------- 1 | {% macro current_schema() %} 2 | current_database() 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/date_from_parts.sql: -------------------------------------------------------------------------------- 1 | {% macro date_from_parts(year, month, day) %} 2 | make_date({{year}}, {{month}}, {{day}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/dateaddog.sql: -------------------------------------------------------------------------------- 1 | {% macro dateadd(unit, measure, base) %} 2 | CASE 3 | WHEN lower({{unit}}) = 'year' THEN {{base}} + make_interval({{measure}}) 4 | WHEN lower({{unit}}) = 'month' THEN {{base}} + make_interval(0, {{measure}}) 5 | WHEN lower({{unit}}) = 'day' THEN {{base}} + make_interval(0, 0, 0, {{measure}}) 6 | WHEN lower({{unit}}) = 'hour' THEN {{base}} + make_interval(0, 0, 0, 0, {{measure}}) 7 | WHEN lower({{unit}}) = 'minute' THEN {{base}} + make_interval(0, 0, 0, 0, 0, {{measure}}) 8 | WHEN lower({{unit}}) = 'second' THEN {{base}} + make_interval(0, 0, 0, 0, 0, 0, {{measure}}) 9 | END 10 | {% endmacro %} 11 | -------------------------------------------------------------------------------- /integration_tests/macros/dayname.sql: -------------------------------------------------------------------------------- 1 | {% macro dayname(arg) %} 2 | CASE 3 | WHEN datediff(CAST({{arg}} AS DATE), DATE'1799-12-29') % 7 = 0 THEN 'Sun' 4 | WHEN datediff(CAST({{arg}} AS DATE), DATE'1799-12-29') % 7 = 1 THEN 'Mon' 5 | WHEN datediff(CAST({{arg}} AS DATE), DATE'1799-12-29') % 7 = 2 THEN 'Tue' 6 | WHEN datediff(CAST({{arg}} AS DATE), DATE'1799-12-29') % 7 = 3 THEN 'Wed' 7 | WHEN datediff(CAST({{arg}} AS DATE), DATE'1799-12-29') % 7 = 4 THEN 'Thu' 8 | WHEN datediff(CAST({{arg}} AS DATE), DATE'1799-12-29') % 7 = 5 THEN 'Fri' 9 | ELSE 'Sat' END 10 | {% endmacro %} 11 | -------------------------------------------------------------------------------- /integration_tests/macros/dayofweekiso.sql: -------------------------------------------------------------------------------- 1 | {% macro dayofweekiso(arg) %} 2 | EXTRACT(DAYOFWEEK_ISO FROM {{arg}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/dbt_housekeeping.sql: -------------------------------------------------------------------------------- 1 | {% macro dbt_housekeeping() -%} 2 | '{{ invocation_id }}'::string as dbt_batch_id, 3 | '{{ run_started_at }}'::timestamp as dbt_batch_ts 4 | {%- endmacro %} 5 | -------------------------------------------------------------------------------- /integration_tests/macros/div0.sql: -------------------------------------------------------------------------------- 1 | {% macro div0(arg1, arg2) %} 2 | CASE WHEN {{arg2}} = 0 THEN 0 ELSE {{arg1}} / {{arg2}} END; 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/dt_convert_money.sql: -------------------------------------------------------------------------------- 1 | {% macro money(col) -%} 2 | ::decimal(16,4) 3 | {%- endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/endswith.sql: -------------------------------------------------------------------------------- 1 | {% macro endswith(arg1, arg2) %} 2 | substr({{arg1}}, -length({{arg2}}), length({{arg2}})) = {{arg2}}; 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/equal_null.sql: -------------------------------------------------------------------------------- 1 | {% macro equal_null(arg1, arg2) %} 2 | {{arg1}} <=> {{arg2}} 3 | {% endmacro %} -------------------------------------------------------------------------------- /integration_tests/macros/exclude.sql: -------------------------------------------------------------------------------- 1 | {%- macro exclude() -%} 2 | 3 | {%- set all_args = [] -%} 4 | {% for col in kwargs.items() -%} 5 | {%- do all_args.append(col) -%} 6 | {%- endfor -%} 7 | 8 | 9 | except({{ all_args|join(', ') }}) 10 | {%- endmacro -%} 11 | -------------------------------------------------------------------------------- /integration_tests/macros/from_utc_timestamp.sql: -------------------------------------------------------------------------------- 1 | {% macro from_utc_timestamp(source, target, stamp) %} 2 | from_utc_timestamp(to_utc_timestamp({{stamp}}, {{source}}), {{target}}) 3 | {% endmacro %} -------------------------------------------------------------------------------- /integration_tests/macros/getdate.sql: -------------------------------------------------------------------------------- 1 | {% macro getdate() %} 2 | current_timestamp() 3 | {% endmacro %} -------------------------------------------------------------------------------- /integration_tests/macros/hex_decode_string.sql: -------------------------------------------------------------------------------- 1 | {% macro hex_decode_string(arg1) %} 2 | decode(unhex({{arg1}}), 'UTF-8') 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/insert.sql: -------------------------------------------------------------------------------- 1 | {% macro insert(base, pos, len, ins) %} 2 | overlay({{base}}, {{ins}}, {{pos}}, {{len}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/is_null_value.sql: -------------------------------------------------------------------------------- 1 | {% macro is_null_value(string) %} 2 | isnull({{string}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/json_extract_path_text.sql: -------------------------------------------------------------------------------- 1 | {% macro json_extract_path_text(expr, key) %} 2 | get_json_object({{expr}}, '$.{{key}}') 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/listagg.sql: -------------------------------------------------------------------------------- 1 | {% macro listagg(arg, delim) %} 2 | array_join(sort_array(collect_list({{arg}})), "{{delim}}") 3 | 4 | {% endmacro %} -------------------------------------------------------------------------------- /integration_tests/macros/md5_binary.sql: -------------------------------------------------------------------------------- 1 | {% macro md5_binary(arg) %} 2 | md5({{arg}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/monthname.sql: -------------------------------------------------------------------------------- 1 | {% macro monthname(arg) %} 2 | CASE 3 | WHEN EXTRACT(MONTH FROM {{arg}}) = 1 THEN 'Jan' 4 | WHEN EXTRACT(MONTH FROM {{arg}}) = 2 THEN 'Feb' 5 | WHEN EXTRACT(MONTH FROM {{arg}}) = 3 THEN 'Mar' 6 | WHEN EXTRACT(MONTH FROM {{arg}}) = 4 THEN 'Apr' 7 | WHEN EXTRACT(MONTH FROM {{arg}}) = 5 THEN 'May' 8 | WHEN EXTRACT(MONTH FROM {{arg}}) = 6 THEN 'Jun' 9 | WHEN EXTRACT(MONTH FROM {{arg}}) = 7 THEN 'Jul' 10 | WHEN EXTRACT(MONTH FROM {{arg}}) = 8 THEN 'Aug' 11 | WHEN EXTRACT(MONTH FROM {{arg}}) = 9 THEN 'Sep' 12 | WHEN EXTRACT(MONTH FROM {{arg}}) = 10 THEN 'Oct' 13 | WHEN EXTRACT(MONTH FROM {{arg}}) = 11 THEN 'Nov' 14 | ELSE 'Dec' END 15 | {% endmacro %} 16 | -------------------------------------------------------------------------------- /integration_tests/macros/nullifzero.sql: -------------------------------------------------------------------------------- 1 | {% macro nullifzero(arg) %} 2 | nullif({{arg}}, 0) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/parse_json.sql: -------------------------------------------------------------------------------- 1 | {% macro parse_json(string) %} 2 | from_json({{string}}, schema_of_json({{string}})) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/previous_day.sql: -------------------------------------------------------------------------------- 1 | {% macro previous_day(arg, day) %} 2 | CASE WHEN substr(dayname({{arg}}), 1, 2) = substr({{day}}, 1, 2) THEN {{arg}} - INTERVAL 7 DAY 3 | ELSE next_day({{arg}}, {{day}}) - INTERVAL 7 DAY END; 4 | {% endmacro %} 5 | -------------------------------------------------------------------------------- /integration_tests/macros/seq1.sql: -------------------------------------------------------------------------------- 1 | {% macro seq1() %} 2 | monotonically_increasing_id() 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/seq2.sql: -------------------------------------------------------------------------------- 1 | {% macro seq2(arg) %} 2 | monotonically_increasing_id() 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/seq4.sql: -------------------------------------------------------------------------------- 1 | {% macro seq4() %} 2 | monotonically_increasing_id() 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/seq8.sql: -------------------------------------------------------------------------------- 1 | {% macro seq8() %} 2 | monotonically_increasing_id() 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/sha1hex.sql: -------------------------------------------------------------------------------- 1 | {% macro sha1hex(arg, len) %} 2 | sha1({{arg}}, {{len}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/sha2_hex.sql: -------------------------------------------------------------------------------- 1 | {% macro sha2_hex(arg, len) %} 2 | sha2({{arg}}, {{len}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/split_part.sql: -------------------------------------------------------------------------------- 1 | {% macro split_part(arg, delim, part) %} 2 | element_at(split({{arg}}, {{delim}}), {{part}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/square.sql: -------------------------------------------------------------------------------- 1 | {% macro square(arg) %} 2 | {{arg}} * {{arg}} 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/startswith.sql: -------------------------------------------------------------------------------- 1 | {% macro startswith(arg1, arg2) %} 2 | position({{arg2}}, {{arg1}}) = 1 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/strtok.sql: -------------------------------------------------------------------------------- 1 | {% macro strtok(arg, delim, part) %} 2 | element_at(split({{arg}}, {{delim}}), {{part}} ) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/strtok_to_array.sql: -------------------------------------------------------------------------------- 1 | {% macro strtok_to_array(arg, delim) %} 2 | split({{arg}}, concat("[", {{delim}}, "]")) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/sysdate.sql: -------------------------------------------------------------------------------- 1 | {% macro sysdate() %} 2 | to_utc_timestamp(current_timestamp(), current_timezone()); 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/systimestamp.sql: -------------------------------------------------------------------------------- 1 | {% macro systimestamp() %} 2 | current_timestamp() 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/timediff.sql: -------------------------------------------------------------------------------- 1 | {% macro timediff(unit, arg1,arg2) %} 2 | CASE 3 | WHEN lower({{unit}}) = 'year' THEN EXTRACT(YEAR FROM {{arg2}}) - EXTRACT(YEAR FROM {{arg1}}) 4 | WHEN lower({{unit}}) = 'month' THEN (EXTRACT(YEAR FROM {{arg2}}) * 12 + EXTRACT(MONTH FROM {{arg2}})) 5 | - (EXTRACT(YEAR FROM {{arg1}}) * 12 + EXTRACT(MONTH FROM {{arg1}})) 6 | WHEN lower({{unit}}) = 'day' THEN datediff(CAST({{arg2}} AS DATE), CAST({{arg1}} AS DATE)) 7 | WHEN lower({{unit}}) = 'hour' THEN EXTRACT(HOUR FROM {{arg2}}) - EXTRACT(HOUR FROM {{arg1}}) 8 | WHEN lower({{unit}}) = 'minute' THEN (EXTRACT(HOUR FROM {{arg2}}) * 60 + EXTRACT(MINUTE FROM {{arg2}})) 9 | - (EXTRACT(HOURs FROM {{arg1}}) * 60 + EXTRACT(MINUTE FROM {{arg1}})) 10 | WHEN lower({{unit}}) = 'second' THEN (EXTRACT(HOUR FROM {{arg2}}) * 3600 + EXTRACT(MINUTE FROM {{arg2}}) * 60 + EXTRACT(SECOND FROM {{arg2}})) 11 | - (EXTRACT(HOUR FROM {{arg2}}) * 3600 + EXTRACT(MINUTE FROM {{arg2}}) * 60 + EXTRACT(SECOND FROM {{arg2}})) 12 | END 13 | {% endmacro %} 14 | -------------------------------------------------------------------------------- /integration_tests/macros/timestamp_from_parts.sql: -------------------------------------------------------------------------------- 1 | {% macro timestamp_from_parts(year, month, day, hour, minute, second) %} 2 | make_timestamp({{year}}, {{month}}, {{day}}, {{hour}}, {{minute}}, {{second}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/timestampadd.sql: -------------------------------------------------------------------------------- 1 | {% macro timestampadd(unit, measure, base) %} 2 | CASE 3 | WHEN lower({{unit}}) = 'year' THEN {{base}} + make_interval({{measure}}) 4 | WHEN lower({{unit}}) = 'month' THEN {{base}} + make_interval(0, {{measure}}) 5 | WHEN lower({{unit}}) = 'day' THEN {{base}} + make_interval(0, 0, 0, {{measure}}) 6 | WHEN lower({{unit}}) = 'hour' THEN {{base}} + make_interval(0, 0, 0, 0, {{measure}}) 7 | WHEN lower({{unit}}) = 'minute' THEN {{base}} + make_interval(0, 0, 0, 0, 0, {{measure}}) 8 | WHEN lower({{unit}}) = 'second' THEN {{base}} + make_interval(0, 0, 0, 0, 0, 0, {{measure}}) 9 | END 10 | {% endmacro %} 11 | -------------------------------------------------------------------------------- /integration_tests/macros/timestampdiff.sql: -------------------------------------------------------------------------------- 1 | {% macro timestampdiff(unit, arg1,arg2) %} 2 | CASE 3 | WHEN lower({{unit}}) = 'year' THEN EXTRACT(YEAR FROM {{arg2}}) - EXTRACT(YEAR FROM {{arg1}}) 4 | WHEN lower({{unit}}) = 'month' THEN (EXTRACT(YEAR FROM {{arg2}}) * 12 + EXTRACT(MONTH FROM {{arg2}})) 5 | - (EXTRACT(YEAR FROM {{arg1}}) * 12 + EXTRACT(MONTH FROM {{arg1}})) 6 | WHEN lower({{unit}}) = 'day' THEN datediff(CAST({{arg2}} AS DATE), CAST({{arg1}} AS DATE)) 7 | WHEN lower({{unit}}) = 'hour' THEN EXTRACT(HOUR FROM {{arg2}}) - EXTRACT(HOUR FROM {{arg1}}) 8 | WHEN lower({{unit}}) = 'minute' THEN (EXTRACT(HOUR FROM {{arg2}}) * 60 + EXTRACT(MINUTE FROM {{arg2}})) 9 | - (EXTRACT(HOUR FROM {{arg1}}) * 60 + EXTRACT(MINUTE FROM {{arg1}})) 10 | WHEN lower({{unit}}) = 'second' THEN (EXTRACT(HOUR FROM {{arg2}}) * 3600 + EXTRACT(MINUTE FROM {{arg2}}) * 60 + EXTRACT(SECOND FROM {{arg2}})) 11 | - (EXTRACT(HOUR FROM {{arg2}}) * 3600 + EXTRACT(MINUTE FROM {{arg2}}) * 60 + EXTRACT(SECOND FROM {{arg2}})) 12 | END 13 | {% endmacro %} 14 | -------------------------------------------------------------------------------- /integration_tests/macros/to_array.sql: -------------------------------------------------------------------------------- 1 | {% macro to_array(expr) %} 2 | array({{expr}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/to_binary.sql: -------------------------------------------------------------------------------- 1 | {% macro to_binary(arg) %} 2 | unhex({{arg}}) 3 | {% endmacro %} -------------------------------------------------------------------------------- /integration_tests/macros/to_boolean.sql: -------------------------------------------------------------------------------- 1 | {% macro to_boolean(arg) %} 2 | CASE 3 | WHEN lower({{arg}}) = 'false' THEN FALSE 4 | WHEN lower({{arg}}) = 'f' THEN FALSE 5 | WHEN lower({{arg}}) = 'no' THEN FALSE 6 | WHEN lower({{arg}}) = 'n' THEN FALSE 7 | WHEN lower({{arg}}) = 'off' THEN FALSE 8 | WHEN lower({{arg}}) = '0' THEN FALSE 9 | WHEN lower({{arg}}) = 'true' THEN TRUE 10 | WHEN lower({{arg}}) = 't' THEN TRUE 11 | WHEN lower({{arg}}) = 'yes' THEN TRUE 12 | WHEN lower({{arg}}) = 'y' THEN TRUE 13 | WHEN lower({{arg}}) = 'on' THEN TRUE 14 | WHEN lower({{arg}}) = '1' THEN TRUE 15 | 16 | ELSE NULL 17 | END 18 | {% endmacro %} 19 | -------------------------------------------------------------------------------- /integration_tests/macros/to_char.sql: -------------------------------------------------------------------------------- 1 | {% macro to_char(arg) %} 2 | cast({{arg}} as string) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/to_decimal.sql: -------------------------------------------------------------------------------- 1 | {% macro to_decimal(expr, format, precision, scale) %} 2 | 3 | 4 | {% if scale %} 5 | 6 | 7 | 8 | 9 | cast({{expr}} as decimal({{precision}}, {{scale}})) 10 | 11 | 12 | {% elif precision %} 13 | 14 | cast({{expr}} as decimal({{format}}, {{precision}})) 15 | 16 | 17 | {% elif format %} 18 | 19 | to_number({{expr}}, "{{format}}") 20 | 21 | 22 | {% else %} 23 | 24 | cast({{expr}} as decimal(38, 0)) 25 | 26 | {% endif %} 27 | 28 | {% endmacro %} 29 | -------------------------------------------------------------------------------- /integration_tests/macros/to_number.sql: -------------------------------------------------------------------------------- 1 | {% macro to_number(expr, format, precision, scale) %} 2 | 3 | 4 | {% if scale %} 5 | 6 | 7 | 8 | 9 | cast({{expr}} as decimal({{precision}}, {{scale}})) 10 | 11 | 12 | {% elif precision %} 13 | 14 | cast({{expr}} as decimal({{format}}, {{precision}})) 15 | 16 | 17 | {% elif format %} 18 | 19 | to_number({{expr}}, "{{format}}") 20 | 21 | 22 | {% else %} 23 | 24 | cast({{expr}} as decimal(38, 0)) 25 | 26 | {% endif %} 27 | 28 | {% endmacro %} 29 | -------------------------------------------------------------------------------- /integration_tests/macros/to_numeric.sql: -------------------------------------------------------------------------------- 1 | {% macro to_numeric(expr, format, precision, scale) %} 2 | 3 | 4 | {% if scale %} 5 | 6 | 7 | 8 | 9 | cast({{expr}} as decimal({{precision}}, {{scale}})) 10 | 11 | 12 | {% elif precision %} 13 | 14 | cast({{expr}} as decimal({{format}}, {{precision}})) 15 | 16 | 17 | {% elif format %} 18 | 19 | to_number({{expr}}, "{{format}}") 20 | 21 | 22 | {% else %} 23 | 24 | cast({{expr}} as decimal(38, 0)) 25 | 26 | {% endif %} 27 | 28 | {% endmacro %} 29 | -------------------------------------------------------------------------------- /integration_tests/macros/to_time.sql: -------------------------------------------------------------------------------- 1 | {% macro to_time(expr) %} 2 | to_timestamp(expr, 'HH:mm:ss') 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/to_timestamp_ntz.sql: -------------------------------------------------------------------------------- 1 | {% macro to_timestamp_ntz(arg) %} 2 | to_timestamp(arg) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/to_varchar.sql: -------------------------------------------------------------------------------- 1 | {% macro to_varchar(expr, format) %} 2 | 3 | {% if format %} 4 | 5 | case when typeof({{expr}}) = 'date' 6 | then to_date({{expr}}, {{format}})::string 7 | when typeof({{expr}}) = 'timestamp' 8 | then to_timestamp({{expr}}, {{format}})::string 9 | when typeof({{expr}}) = 'binary' 10 | then to_binary({{expr}}, {{format}})::string 11 | else to_char({{expr}}, {{format}})::string 12 | end 13 | 14 | {% else %} 15 | 16 | cast({{expr}} as string) 17 | 18 | 19 | 20 | {% endif %} 21 | 22 | {% endmacro %} 23 | -------------------------------------------------------------------------------- /integration_tests/macros/try_cast.sql: -------------------------------------------------------------------------------- 1 | {% macro try_cast(column_name, precision=2) %} 2 | cast({{column_name}} as string) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/try_to_decimal.sql: -------------------------------------------------------------------------------- 1 | {% macro try_to_decimal(expr, format, precision, scale) %} 2 | 3 | 4 | {% if scale %} 5 | 6 | 7 | 8 | 9 | try_cast({{expr}} as decimal({{precision}}, {{scale}})) 10 | 11 | 12 | {% elif precision %} 13 | 14 | try_cast({{expr}} as decimal({{format}}, {{precision}})) 15 | 16 | 17 | {% elif format %} 18 | 19 | try_to_number({{expr}}, "{{format}}") 20 | 21 | 22 | {% else %} 23 | 24 | try_cast({{expr}} as decimal(38, 0)) 25 | 26 | {% endif %} 27 | 28 | {% endmacro %} 29 | -------------------------------------------------------------------------------- /integration_tests/macros/try_to_number.sql: -------------------------------------------------------------------------------- 1 | {% macro try_to_number(expr, format, precision, scale) %} 2 | 3 | 4 | {% if scale %} 5 | 6 | 7 | 8 | 9 | try_cast({{expr}} as decimal({{precision}}, {{scale}})) 10 | 11 | 12 | {% elif precision %} 13 | 14 | try_cast({{expr}} as decimal({{format}}, {{precision}})) 15 | 16 | 17 | {% elif format %} 18 | 19 | try_to_number({{expr}}, "{{format}}") 20 | 21 | 22 | {% else %} 23 | 24 | try_cast({{expr}} as decimal(38, 0)) 25 | 26 | {% endif %} 27 | 28 | {% endmacro %} 29 | -------------------------------------------------------------------------------- /integration_tests/macros/try_to_numeric.sql: -------------------------------------------------------------------------------- 1 | {% macro try_to_numeric(expr, format, precision, scale) %} 2 | 3 | 4 | {% if scale %} 5 | 6 | 7 | 8 | 9 | try_cast({{expr}} as decimal({{precision}}, {{scale}})) 10 | 11 | 12 | {% elif precision %} 13 | 14 | try_cast({{expr}} as decimal({{format}}, {{precision}})) 15 | 16 | 17 | {% elif format %} 18 | 19 | try_to_number({{expr}}, "{{format}}") 20 | 21 | 22 | {% else %} 23 | 24 | try_cast({{expr}} as decimal(38, 0)) 25 | 26 | {% endif %} 27 | 28 | {% endmacro %} 29 | -------------------------------------------------------------------------------- /integration_tests/macros/uniform.sql: -------------------------------------------------------------------------------- 1 | {% macro uniform(min, max, double) %} 2 | {{min}} + ({{max}} - {{min}}) * {{rand}} 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/uuid_string.sql: -------------------------------------------------------------------------------- 1 | {% macro uuid_string() %} 2 | uuid() 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/week.sql: -------------------------------------------------------------------------------- 1 | {% macro week(stamp) %} 2 | EXTRACT(WEEK FROM {{stamp}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/weekiso.sql: -------------------------------------------------------------------------------- 1 | {% macro weekiso(arg) %} 2 | extract (week from {{arg}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/yearofweek.sql: -------------------------------------------------------------------------------- 1 | {% macro yearofweek(arg) %} 2 | extract(year from {{arg}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/yearofweekiso.sql: -------------------------------------------------------------------------------- 1 | {% macro yearofweekiso(arg) %} 2 | extract(year from {{arg}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/macros/zeroifnull.sql: -------------------------------------------------------------------------------- 1 | {% macro zeroifnull(column_name) %} 2 | nvl({{column_name}}, 0) 3 | {% endmacro %} -------------------------------------------------------------------------------- /integration_tests/profiles.yml: -------------------------------------------------------------------------------- 1 | integration_tests: 2 | target: databricks 3 | 4 | outputs: 5 | 6 | snowflake: 7 | type: snowflake 8 | account: "{{ env_var('SNOWFLAKE_TEST_ACCOUNT') }}" 9 | user: "{{ env_var('SNOWFLAKE_TEST_USER') }}" 10 | password: "{{ env_var('SNOWFLAKE_TEST_PASSWORD') }}" 11 | role: "{{ env_var('SNOWFLAKE_TEST_ROLE') }}" 12 | database: "{{ env_var('SNOWFLAKE_TEST_DATABASE') }}" 13 | warehouse: "{{ env_var('SNOWFLAKE_TEST_WAREHOUSE') }}" 14 | schema: "{{ env_var('SNOWFLAKE_TEST_SCHEMA') }}" 15 | 16 | 17 | databricks: 18 | type: databricks 19 | method: http 20 | catalog: "{{ env_var('DATABRICKS_TEST_CATALOG') }}" 21 | schema: "{{ env_var('DATABRICKS_TEST_SCHEMA') }}" 22 | host: "{{ env_var('DATABRICKS_TEST_HOST') }}" 23 | 24 | token: "{{ env_var('DATABRICKS_TEST_TOKEN') }}" 25 | http_path: "{{ env_var('DATABRICKS_TEST_PATH') }}" 26 | -------------------------------------------------------------------------------- /integration_tests/regexit.py: -------------------------------------------------------------------------------- 1 | import os 2 | os.chdir("/home/circleci/project/integration_tests") 3 | syntaxakpath = 'syntaxak.sql' 4 | #functionakpath = 'functionak.sql' 5 | pyakpath = 'tresak.py' 6 | lookerakpath = 'unoak.lkml' 7 | 8 | with open(syntaxakpath, 'r+') as file: 9 | syntaxak = file.read() 10 | 11 | #with open(functionakpath, 'r+') as file: 12 | # functionak = file.read() 13 | 14 | with open(lookerakpath, 'r+') as file: 15 | lookerak = file.read() 16 | 17 | with open(pyakpath, 'r+') as file: 18 | pyak = file.read() 19 | 20 | os.chdir("/home/circleci/project/models/redshift_to_databricks") 21 | syntaxgenpath = 'customerrs.sql' 22 | 23 | with open(syntaxgenpath, 'r+') as file: 24 | syntaxgen = file.read() 25 | 26 | os.chdir("/home/circleci/project/tmp/beyondsqltest") 27 | pygenpath = "testpyfiles_to_databricks/tres.py" 28 | lookergenpath = "testlookmlfiles_to_databricks/uno.lkml" 29 | 30 | with open(pygenpath, 'r+') as file: 31 | pygen = file.read() 32 | 33 | with open(lookergenpath, 'r+') as file: 34 | lookergen = file.read() 35 | 36 | 37 | assert syntaxak == syntaxgen 38 | assert pyak == pygen 39 | assert lookerak == lookergen 40 | 41 | print('wooho, test passed!!') 42 | -------------------------------------------------------------------------------- /integration_tests/seeds/springbrickstests.csv: -------------------------------------------------------------------------------- 1 | function_name,input,expected_output 2 | any_value,, 3 | approx_top_k,, 4 | approximate_count_distinct,, 5 | approximate_jaccard_index,, 6 | approximate_similarity,, 7 | array_agg,coffee,"coffee, iced tea, latte, tea" 8 | array_agg,iced tea,"coffee, iced tea, latte, tea" 9 | array_agg,latte,"coffee, iced tea, latte, tea" 10 | array_agg,tea,"coffee, iced tea, latte, tea" 11 | array_append,, 12 | array_cat,"coffee, iced tea","coffee, iced tea, latte, tea" 13 | array_cat,"latte,tea","coffee, iced tea, latte, tea" 14 | array_compact,, 15 | array_construct,, 16 | array_construct_compact,, 17 | array_insert,, 18 | array_intersection,, 19 | array_size,, 20 | array_slice,, 21 | array_to_string,, 22 | arrayagg,, 23 | as_char,, 24 | as_date,, 25 | as_integer,, 26 | as_number,, 27 | as_varchar,, 28 | base64_decode_binary,, 29 | base64_decode_string,, 30 | base64_encode,, 31 | bitand,, 32 | booland_agg,, 33 | boolor_agg,, 34 | boolxor_agg,, 35 | charindex,, 36 | check_json,, 37 | compress,, 38 | contains,coffee,FALSE 39 | contains,iced tea,TRUE 40 | contains,latte,TRUE 41 | contains,tea,TRUE 42 | contains,NULL,NULL 43 | control.harmonize_compact,, 44 | convert_timezone,, 45 | date_from_parts,"{""col1"":""2023"",""col2"":""01"",""col3"":""10""}",10/1/2023 46 | dateadd,"{""col1"":""day"",""col2"":""7"",""col3"":""2023-01-10""}",17/1/2023 47 | dateadd,"{""col1"":""minute"",""col2"":""11"",""col3"":""2023-01-10 7:13""}",10/1/2023 7:24 48 | dayname,3/5/2023,Wed 49 | dayname,8/5/2023 11:15,Mon 50 | dayofweekiso,3/5/2023,3 51 | dayofweekiso,8/5/2023 11:15,1 52 | decrypt,, 53 | div0,, 54 | editdistance,, 55 | encrypt,, 56 | endswith,, 57 | enrich_placement_ad_type,, 58 | equal_null,, 59 | get,, 60 | get_ddl,, 61 | get_path,, 62 | getdate,, 63 | hash_agg,, 64 | hex_decode_binary,, 65 | hex_decode_string,, 66 | hll,, 67 | hll_estimate,, 68 | hll_export,, 69 | hll_import,, 70 | iff,, 71 | ilike,, 72 | insert,, 73 | is_boolean,, 74 | is_date,, 75 | is_integer,, 76 | is_null_value,, 77 | is_real,, 78 | is_role_in_session,, 79 | json_extract_path_text,, 80 | last_query_id,, 81 | last_transaction,, 82 | len,, 83 | listagg,, 84 | md5_binary,Snowflake,EDF1439075A83A447FB8B630DDC9C8DE 85 | md5_hex,, 86 | md5_number_lower64,, 87 | md5_number_upper64,, 88 | median,, 89 | minhash,, 90 | minhash_combine,, 91 | mode,, 92 | monthname,1/5/2015,May 93 | monthname,3/4/2015 10:00,Apr 94 | nullifzero,, 95 | object_agg,, 96 | object_construct,, 97 | object_delete,, 98 | object_insert,, 99 | object_keys,, 100 | objectagg,, 101 | parse_json,, 102 | parse_xml,, 103 | percentile_cont,, 104 | percentile_disc,, 105 | previous_day,, 106 | randstr,, 107 | ratio_to_report,, 108 | regexp,, 109 | regexp_count,, 110 | regexp_instr,, 111 | regexp_like,, 112 | regexp_substr,, 113 | seq1,, 114 | seq2,, 115 | seq4,, 116 | seq8,, 117 | sha1_hex,, 118 | sha2_binary,, 119 | sha2_hex,, 120 | split_part,"{11.22.33, ""."", 0}",11 121 | split_part,"{11.22.33, ""."", 1}",11 122 | split_part,"{11.22.33, ""."", 2}",22 123 | split_part,"{11.22.33, ""."", 3}",33 124 | split_part,"{11.22.33, ""."", 4}", 125 | split_part,"{11.22.33, ""."", -1}",33 126 | split_part,"{11.22.33, ""."", -2}",22 127 | split_part,"{11.22.33, ""."", -3}",11 128 | split_part,"{11.22.33, ""."", -4}", 129 | square,, 130 | st_intersects,, 131 | standardize,, 132 | startswith,coffee,FALSE 133 | startswith,iced tea,FALSE 134 | startswith,latte,FALSE 135 | startswith,tea,TRUE 136 | startswith,NULL,NULL 137 | strtok,, 138 | strtok_to_array,"{""col1:""a.b.c"",""col2"", "".""}","[""a"", ""b"", ""c""]" 139 | strtok_to_array,"{""col1"":""user@snowflake.com"", ""col2"":"".@""}","[""user"",""snowflake"",""com""]" 140 | sysdate,, 141 | systimestamp,, 142 | time,, 143 | time_slice,, 144 | timeadd,"{""col1"":""year"", ""col2"":2, ""col3"":""2013-05-08""}","""2015-05-08""" 145 | timeadd,"{""col1"":""hour"", ""col2"":2, ""col3"": ""2013-04-05 02:00:00.000""}","""2015-05-08""" 146 | timediff,"{""col1"":""year"", ""col2"":""2017-01-01"",""col3"":""2019-01-01""}",2 147 | timediff,"{""col1"":""month"", ""col2"":""2017-01-01"", ""col3"":""2017-12-31""}",11 148 | timestamp_from_parts,, 149 | timestamp_ntz_from_parts,, 150 | timestampadd,"{""col1"":year"", ""col2"": 2, ""col3"":""2013-05-08""}","""2015-05-08""" 151 | timestampadd,"{""col1"":""hour"", ""col2"":2, ""col3"":""2013-04-05 00:00:00.000""}","""2013-04-05 02:00:00""" 152 | timestampdiff,"{""col1"":""year"",""col2"": ""2017-01-01"",""col3"": ""2019-01-01""}",2 153 | timestampdiff,"{""col1"":""month"", ""col2"":""2017-01-01"",""col3"": ""2017-12-31""}",11 154 | to_array,1,[1] 155 | to_array,3,[3] 156 | to_binary,"(""col1"": ""SNOW"", ""col2"":utf-8"")",534E4F57 157 | to_boolean,yes,TRUE 158 | to_boolean,no,FALSE 159 | to_boolean,NULL,NULL 160 | to_boolean,1,TRUE 161 | to_boolean,0,FALSE 162 | to_boolean,NULL,NULL 163 | to_char,"{""col1"":'2013-04-05 01:02:03', ""col2"":'mm/dd/yyyy', ""col3"":'hh23:mi hours'}","{""col1"":'04/05/2013', ""col2"":'01:02 hours'}" 164 | to_char,"{""col1"":""03-May-2013""}",3/5/2013 165 | to_char,"{""col1"":""03-May-2013"", ""col2"":""yyyy.mm.dd""}",2013.05.03 166 | to_number,12.3456,12 167 | to_number,98.76546,99 168 | to_number,"{12.3456, 10, 1}",12.3 169 | to_number,"{98.76546, 10, 1}",98.8 170 | to_number,"{12.3456, 10, 8}",12.3456 171 | to_number,"{98.76546, 10, 8}",98.7645 172 | to_double,, 173 | to_geography,, 174 | to_decimal,1, 175 | to_decimal,-12.3, 176 | to_decimal,0, 177 | to_decimal,-0.1, 178 | to_decimal,"{1, '99.9', 9, 5}",1.00000' 179 | to_decimal,"{-12.3, '99.9', 9, 5}",-12.30000' 180 | to_decimal,"{0.0, '99.9', 9, 5}",0.00000' 181 | to_decimal,"{-0.1, '99.9', 9, 5}",-0.10000' 182 | to_decimal,"{1, 'TM9', 9, 5}",1.00000' 183 | to_decimal,"{1, 'TM9', 9, 5}",-12.30000' 184 | to_decimal,"{1, 'TM9', 9, 5}",0.00000' 185 | to_decimal,"{1, 'TM9', 9, 5}",-0.10000' 186 | to_numeric,12.3456,12 187 | to_numeric,98.76546,99 188 | to_numeric,"{12.3456, 10, 1}",12.3 189 | to_numeric,"{98.76546, 10, 1}",98.8 190 | to_numeric,"{12.3456, 10, 8}",12.3456 191 | to_numeric,"{98.76546, 10, 8}",98.7645 192 | to_object,, 193 | to_time,"{""col"":'13:30:00'}",13:30:00' 194 | to_time,"{""col1"":'11.15.00', '""col2"":'HH24.MI.SS'}",11:15:00' 195 | to_timestamp_ltz,, 196 | to_timestamp_ntz,todo, 197 | to_timestamp_tz,todo, 198 | to_varchar,"{""col1"":'2013-04-05 01:02:03', ""col2"":'mm/dd/yyyy, hh24:mi hours'}","{'04/05/2013', '01:02 hours'}" 199 | to_varchar,"{""03-May-2013""}",3/5/2013 200 | to_varchar,"{""col1"":""03-May-2013"", ""col2"":""yyyy.mm.dd""}",2013.05.03 201 | to_variant,, 202 | truncate,, 203 | try_base64_decode_string,, 204 | try_cast,"{""col1"":'05-Mar-2016',""col2"": 'AS TIMESTAMP'}",2016-03-05 00:00:00:000 205 | try_cast,"{""col1"":'05/2016', ""col2"":'AS TIMESTAMP'}",NULL 206 | try_cast,"{""col1"":'ABCD', ""col2"":'AS CHAR(2)'}",NULL 207 | try_cast,"{""col1"":'ABCD',""col2"": 'AS VARCHAR(10)'}",ABCD 208 | try_parse_json,, 209 | try_to_binary,, 210 | try_to_boolean,, 211 | try_to_date,, 212 | try_to_decimal,345.123,345 213 | try_to_decimal,"{345.123, 10, 2}",345.12 214 | try_to_decimal,"{345.123, 4, 2}",NULL 215 | try_to_decimal,"{'$345.12', '$999.00'}",345 216 | try_to_decimal,"{'$345.12', '$999.00', 5, 2}",345.12 217 | try_to_decimal,"{'$345.12', 5, 2}",NULL 218 | try_to_number,345.123,345 219 | try_to_number,"{345.123, 10, 2}",345.12 220 | try_to_number,"{345.123, 4, 2}",NULL 221 | try_to_number,"{'$345.12', '$999.00'}",345 222 | try_to_number,"{'$345.12', '$999.00', 5, 2}",345.12 223 | try_to_number,"{'$345.12', 5, 2}",NULL 224 | try_to_numeric,345.123,345 225 | try_to_numeric,"{345.123, 10, 2}",345.12 226 | try_to_numeric,"{345.123, 4, 2}",NULL 227 | try_to_numeric,"{'$345.12', '$999.00'}",345 228 | try_to_numeric,"{'$345.12', '$999.00', 5, 2}",345.12 229 | try_to_numeric,"{'$345.12', 5, 2}",NULL 230 | try_to_time,, 231 | try_to_timestamp,, 232 | try_to_timestamp_ntz,, 233 | try_to_timestamp_tz,, 234 | unicode,, 235 | uniform,, 236 | uuid_string,, 237 | variance_samp,, 238 | week,2016-01-02 23:39:20.123',53 239 | weekiso,, 240 | xmlget,, 241 | yearofweek,, 242 | yearofweekiso,, 243 | zeroifnull,1,1 244 | zeroifnull,NULL,0 245 | zeroifnull,5,5 246 | zeroifnull,0,0 247 | zeroifnull,3.14159,3.14159 -------------------------------------------------------------------------------- /integration_tests/tests/assert_base64_encode.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | 'Snowflake' as inputuno, 5 | 'U25vd2ZsYWtl' as snowoutputuno, 6 | {{base64_encode('inputuno')}} as dbxoutputuno 7 | 8 | 9 | 10 | 11 | ) 12 | 13 | select * 14 | from test 15 | where (snowoutputuno <> dbxoutputuno) 16 | -------------------------------------------------------------------------------- /integration_tests/tests/assert_contains.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | {{contains('input','"te"')}} as actual_output 7 | from {{ ref('springbrickstests')}} 8 | where function_name = 'contains' 9 | ) 10 | 11 | select * 12 | from test 13 | where expected_output::boolean <> actual_output 14 | -------------------------------------------------------------------------------- /integration_tests/tests/assert_date_from_parts.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | input:col1 as year, 7 | input:col2 as month, 8 | input:col3 as day, 9 | to_date(expected_output,'d/M/yyyy[ H:m]') as expected_output_formatted 10 | 11 | from {{ ref('springbrickstests')}} 12 | where function_name = 'date_from_parts' 13 | ), 14 | 15 | test as ( 16 | select input, 17 | expected_output_formatted, 18 | {{date_from_parts('year','month','day')}} as actual_output 19 | from testraw 20 | 21 | ) 22 | 23 | select * 24 | from test 25 | where expected_output_formatted <> actual_output 26 | -------------------------------------------------------------------------------- /integration_tests/tests/assert_dayname.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | to_date(input,'d/M/yyyy[ H:m]') as input_formatted 7 | 8 | from {{ ref('springbrickstests')}} 9 | where function_name = 'dayname' 10 | ), 11 | 12 | test as ( 13 | select input, 14 | expected_output, 15 | {{dayname('input_formatted')}} as actual_output 16 | from testraw 17 | 18 | ) 19 | 20 | select * 21 | from test 22 | where expected_output <> actual_output 23 | -------------------------------------------------------------------------------- /integration_tests/tests/assert_dayofweekiso.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | to_date(input,'d/M/yyyy[ H:m]') as input_formatted 7 | 8 | from {{ ref('springbrickstests')}} 9 | where function_name = 'dayofweekiso' 10 | ), 11 | 12 | test as ( 13 | select input, 14 | expected_output, 15 | {{dayofweekiso('input_formatted')}} as actual_output 16 | from testraw 17 | 18 | ) 19 | 20 | select * 21 | from test 22 | where expected_output <> actual_output 23 | -------------------------------------------------------------------------------- /integration_tests/tests/assert_json_extract_path_text.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output 6 | 7 | from {{ ref('springbrickstests')}} 8 | where function_name = 'json_extract_path_text' 9 | ), 10 | 11 | test as ( 12 | select input, 13 | expected_output, 14 | {{json_extract_path_text('input','col1')}} as actual_output 15 | from testraw 16 | 17 | ) 18 | 19 | select * 20 | from test 21 | where expected_output <> actual_output 22 | -------------------------------------------------------------------------------- /integration_tests/tests/assert_listagg.sql: -------------------------------------------------------------------------------- 1 | with parse as ( 2 | SELECT inputuno FROM VALUES (41445), (55937), (67781), (80550) AS (inputuno) 3 | ), 4 | 5 | 6 | test as ( 7 | 8 | select 9 | 10 | 11 | "41445 55937 67781 80550" as snowoutputuno, 12 | 13 | {{listagg('inputuno',' ')}} as dbxoutputuno 14 | from parse 15 | group by 1 16 | 17 | ) 18 | 19 | select * 20 | from test 21 | where snowoutputuno <> dbxoutputuno 22 | -------------------------------------------------------------------------------- /integration_tests/tests/assert_listaggdistinct.sql: -------------------------------------------------------------------------------- 1 | with parse as ( 2 | 3 | SELECT inputdos FROM VALUES ('F'), ('O'), ('F'), ('O') AS (inputdos) 4 | 5 | ), 6 | 7 | 8 | test as ( 9 | 10 | select 11 | 12 | 13 | "F|O" as snowoutputdos, 14 | 15 | {{listagg('distinct inputdos','|')}} as dbxoutputdos 16 | from parse 17 | group by 1 18 | 19 | ) 20 | 21 | select * 22 | from test 23 | where snowoutputdos <> dbxoutputdos 24 | -------------------------------------------------------------------------------- /integration_tests/tests/assert_md5_binary.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | {{md5_binary('input')}} as actual_output 7 | from {{ ref('springbrickstests')}} 8 | where function_name = 'md5_binary' 9 | ) 10 | 11 | select * 12 | from test 13 | where expected_output <> upper(actual_output) 14 | -------------------------------------------------------------------------------- /integration_tests/tests/assert_monthname.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | to_date(input,'d/M/yyyy[ H:m]') as input_formatted 7 | 8 | from {{ ref('springbrickstests')}} 9 | where function_name = 'monthname' 10 | ), 11 | 12 | test as ( 13 | select input, 14 | expected_output, 15 | {{monthname('input_formatted')}} as actual_output 16 | from testraw 17 | 18 | ) 19 | 20 | select * 21 | from test 22 | where expected_output <> actual_output 23 | -------------------------------------------------------------------------------- /integration_tests/tests/assert_startswith.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | {{startswith('input','"te"')}} as actual_output 7 | from {{ ref('springbrickstests')}} 8 | where function_name = 'startswith' 9 | 10 | ) 11 | 12 | select * 13 | from test 14 | where expected_output::boolean <> actual_output 15 | -------------------------------------------------------------------------------- /integration_tests/tests/assert_strtok_to_array.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | input:col1 as expr, 7 | input:col2 as delim 8 | 9 | from {{ ref('springbrickstests')}} 10 | where function_name = 'strtok_to_array' 11 | ), 12 | 13 | test as ( 14 | select input, 15 | expected_output, 16 | {{strtok_to_array('expr', 'delim')}} as actual_output 17 | from testraw 18 | 19 | ) 20 | 21 | select * 22 | from test 23 | where expected_output = actual_output::string 24 | -------------------------------------------------------------------------------- /integration_tests/tests/assert_to_array.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | {{to_array('input')}} as actual_output 7 | from {{ ref('springbrickstests')}} 8 | where function_name = 'to_array' 9 | ) 10 | 11 | select * 12 | from test 13 | where expected_output <> actual_output::string 14 | -------------------------------------------------------------------------------- /integration_tests/tests/assert_to_boolean.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | {{to_boolean('input')}} as actual_output 7 | from {{ ref('springbrickstests')}} 8 | where function_name = 'to_boolean' 9 | ) 10 | 11 | select * 12 | from test 13 | where lower(expected_output) <> actual_output::string 14 | -------------------------------------------------------------------------------- /integration_tests/tests/assert_to_time.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | input:col1 as expr 7 | 8 | from {{ ref('springbrickstests')}} 9 | where function_name = 'to_time' 10 | ), 11 | 12 | test as ( 13 | select input, 14 | expected_output, 15 | {{to_time('expr')}} as actual_output 16 | from testraw 17 | 18 | ) 19 | 20 | select * 21 | from test 22 | where expected_output <> actual_output 23 | -------------------------------------------------------------------------------- /integration_tests/tests/assert_week.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | {{week('input')}} as actual_output 7 | from {{ ref('springbrickstests')}} 8 | where function_name = 'week' 9 | ) 10 | 11 | select * 12 | from test 13 | where expected_output <> actual_output::string 14 | -------------------------------------------------------------------------------- /integration_tests/tests/assert_zeroifnull.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | input, 5 | input::decimal(9,5) as inputdec, 6 | expected_output, 7 | {{zeroifnull('inputdec')}} as actual_output 8 | from {{ ref('springbrickstests')}} 9 | where function_name = 'zeroifnull' 10 | ) 11 | 12 | select * 13 | from test 14 | where expected_output <> actual_output 15 | -------------------------------------------------------------------------------- /integration_tests/tests/asset_to_decimal.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | '12.3456' as inputuno, 5 | '12' as snowoutputuno, 6 | {{to_decimal('inputuno')}} as dbxoutputuno, 7 | '12.3' as snowoutputunoa, 8 | '12.3456' as snowoutputunob, 9 | {{to_decimal('inputuno', 10, 1)}} as dbxoutputunoa , 10 | {{to_decimal('inputuno', 10, 8)}} as dbxoutputunob , 11 | '98.76546' as inputdos, 12 | '99' as snowoutputdos, 13 | '98.8' as snowoutputdosa, 14 | '98.76546' as snowoutputdosb, 15 | {{to_decimal('inputdos')}} as dbxoutputdos, 16 | {{to_decimal('inputdos', 10, 1)}} as dbxoutputdosa, 17 | {{to_decimal('inputdos', 10, 8)}} as dbxoutputdosb, 18 | '12.3' as inputtres, 19 | '12.3' as snowoutputtres, 20 | '12.3' as snowoutputtresa, 21 | '12.3' as snowoutputtresb, 22 | {{to_decimal('inputtres', '99.9')}} as dbxoutputtres, 23 | {{to_decimal('inputtres', '99.9', 9, 5)}} as dbxoutputtresa, 24 | {{to_decimal('inputtres', 'TM9', 9, 5)}} as dbxoutputtresb 25 | 26 | 27 | 28 | ) 29 | 30 | select * 31 | from test 32 | where (snowoutputuno <> dbxoutputuno or snowoutputunoa <> dbxoutputunoa or snowoutputunob <> dbxoutputunob 33 | or snowoutputdos <> dbxoutputdos or snowoutputdosa <> dbxoutputdosa or snowoutputdosb <> dbxoutputdosb 34 | or snowoutputtres <> dbxoutputtres or snowoutputtresa <> dbxoutputtresa or snowoutputtresb <> dbxoutputtresb) -------------------------------------------------------------------------------- /integration_tests/tests/asset_to_number.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | '12.3456' as inputuno, 5 | '12' as snowoutputuno, 6 | {{to_number('inputuno')}} as dbxoutputuno, 7 | '12.3' as snowoutputunoa, 8 | '12.3456' as snowoutputunob, 9 | {{to_number('inputuno', 10, 1)}} as dbxoutputunoa , 10 | {{to_number('inputuno', 10, 8)}} as dbxoutputunob , 11 | '98.76546' as inputdos, 12 | '99' as snowoutputdos, 13 | '98.8' as snowoutputdosa, 14 | '98.76546' as snowoutputdosb, 15 | {{to_number('inputdos')}} as dbxoutputdos, 16 | {{to_number('inputdos', 10, 1)}} as dbxoutputdosa, 17 | {{to_number('inputdos', 10, 8)}} as dbxoutputdosb, 18 | '12.3' as inputtres, 19 | '12.3' as snowoutputtres, 20 | '12.3' as snowoutputtresa, 21 | '12.3' as snowoutputtresb, 22 | {{to_number('inputtres', '99.9')}} as dbxoutputtres, 23 | {{to_number('inputtres', '99.9', 9, 5)}} as dbxoutputtresa, 24 | {{to_number('inputtres', 'TM9', 9, 5)}} as dbxoutputtresb 25 | 26 | 27 | 28 | ) 29 | 30 | select * 31 | from test 32 | where (snowoutputuno <> dbxoutputuno or snowoutputunoa <> dbxoutputunoa or snowoutputunob <> dbxoutputunob 33 | or snowoutputdos <> dbxoutputdos or snowoutputdosa <> dbxoutputdosa or snowoutputdosb <> dbxoutputdosb 34 | or snowoutputtres <> dbxoutputtres or snowoutputtresa <> dbxoutputtresa or snowoutputtresb <> dbxoutputtresb) -------------------------------------------------------------------------------- /integration_tests/tests/asset_to_numeric.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | '12.3456' as inputuno, 5 | '12' as snowoutputuno, 6 | {{to_numeric('inputuno')}} as dbxoutputuno, 7 | '12.3' as snowoutputunoa, 8 | '12.3456' as snowoutputunob, 9 | {{to_numeric('inputuno', 10, 1)}} as dbxoutputunoa , 10 | {{to_numeric('inputuno', 10, 8)}} as dbxoutputunob , 11 | '98.76546' as inputdos, 12 | '99' as snowoutputdos, 13 | '98.8' as snowoutputdosa, 14 | '98.76546' as snowoutputdosb, 15 | {{to_numeric('inputdos')}} as dbxoutputdos, 16 | {{to_numeric('inputdos', 10, 1)}} as dbxoutputdosa, 17 | {{to_numeric('inputdos', 10, 8)}} as dbxoutputdosb, 18 | '12.3' as inputtres, 19 | '12.3' as snowoutputtres, 20 | '12.3' as snowoutputtresa, 21 | '12.3' as snowoutputtresb, 22 | {{to_numeric('inputtres', '99.9')}} as dbxoutputtres, 23 | {{to_numeric('inputtres', '99.9', 9, 5)}} as dbxoutputtresa, 24 | {{to_numeric('inputtres', 'TM9', 9, 5)}} as dbxoutputtresb 25 | 26 | 27 | 28 | ) 29 | 30 | select * 31 | from test 32 | where (snowoutputuno <> dbxoutputuno or snowoutputunoa <> dbxoutputunoa or snowoutputunob <> dbxoutputunob 33 | or snowoutputdos <> dbxoutputdos or snowoutputdosa <> dbxoutputdosa or snowoutputdosb <> dbxoutputdosb 34 | or snowoutputtres <> dbxoutputtres or snowoutputtresa <> dbxoutputtresa or snowoutputtresb <> dbxoutputtresb) -------------------------------------------------------------------------------- /integration_tests/tests/asset_try_to_decimal.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | '345.123' as inputuno, 5 | '345' as snowoutputuno, 6 | {{try_to_decimal('inputuno')}} as dbxoutputuno, 7 | '345.12' as snowoutputunoa, 8 | 'NULL' as snowoutputunob, 9 | {{try_to_decimal('inputuno', 10, 2)}} as dbxoutputunoa , 10 | {{try_to_decimal('inputuno', 4, 2)}} as dbxoutputunob , 11 | '$345.12' as inputdos, 12 | '345.12' as snowoutputdos, 13 | 'NULL' as snowoutputdosb, 14 | {{try_to_decimal('inputdos', "$999.00")}} as dbxoutputdos, 15 | {{try_to_decimal('inputdos', 5, 2)}} as dbxoutputdosb 16 | 17 | 18 | 19 | ) 20 | 21 | select * 22 | from test 23 | where (snowoutputuno <> dbxoutputuno or snowoutputunoa <> dbxoutputunoa 24 | or snowoutputdos <> dbxoutputdos) 25 | -------------------------------------------------------------------------------- /integration_tests/tests/asset_try_to_number.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | '345.123' as inputuno, 5 | '345' as snowoutputuno, 6 | {{try_to_number('inputuno')}} as dbxoutputuno, 7 | '345.12' as snowoutputunoa, 8 | 'NULL' as snowoutputunob, 9 | {{try_to_number('inputuno', 10, 2)}} as dbxoutputunoa , 10 | {{try_to_number('inputuno', 4, 2)}} as dbxoutputunob , 11 | '$345.12' as inputdos, 12 | '345.12' as snowoutputdos, 13 | 'NULL' as snowoutputdosb, 14 | {{try_to_number('inputdos', "$999.00")}} as dbxoutputdos, 15 | {{try_to_number('inputdos', 5, 2)}} as dbxoutputdosb 16 | 17 | 18 | 19 | ) 20 | 21 | select * 22 | from test 23 | where (snowoutputuno <> dbxoutputuno or snowoutputunoa <> dbxoutputunoa 24 | or snowoutputdos <> dbxoutputdos) 25 | -------------------------------------------------------------------------------- /integration_tests/tests/asset_try_to_numeric.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | '345.123' as inputuno, 5 | '345' as snowoutputuno, 6 | {{try_to_numeric('inputuno')}} as dbxoutputuno, 7 | '345.12' as snowoutputunoa, 8 | 'NULL' as snowoutputunob, 9 | {{try_to_numeric('inputuno', 10, 2)}} as dbxoutputunoa , 10 | {{try_to_numeric('inputuno', 4, 2)}} as dbxoutputunob , 11 | '$345.12' as inputdos, 12 | '345.12' as snowoutputdos, 13 | 'NULL' as snowoutputdosb, 14 | {{try_to_numeric('inputdos', "$999.00")}} as dbxoutputdos, 15 | {{try_to_numeric('inputdos', 5, 2)}} as dbxoutputdosb 16 | 17 | 18 | 19 | ) 20 | 21 | select * 22 | from test 23 | where (snowoutputuno <> dbxoutputuno or snowoutputunoa <> dbxoutputunoa 24 | or snowoutputdos <> dbxoutputdos) 25 | -------------------------------------------------------------------------------- /integration_tests/tests/readme.md: -------------------------------------------------------------------------------- 1 | The purpose of this directory is to trigger end to end unit tests that showcase how given a specific input, the databricks macro invocation output matches the snowflake output. / To validate this first execute dbt seed and then run dbt test. In the main branch of this source code the test success rate should always be 100%. 2 | -------------------------------------------------------------------------------- /integration_tests/tests/timediff.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | input:col1 as unit, 7 | input:col2 as timeuno, 8 | input:col3 as timedos 9 | 10 | from {{ ref('springbrickstests')}} 11 | where function_name = 'timediff' 12 | ), 13 | 14 | test as ( 15 | select input, 16 | expected_output, 17 | {{timediff('unit', 'timeuno', 'timedos')}} as actual_output 18 | from testraw 19 | 20 | ) 21 | 22 | select * 23 | from test 24 | where expected_output <> actual_output 25 | -------------------------------------------------------------------------------- /integration_tests/tests/timestampadd.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | input:col1 as unit, 7 | input:col2 as measure, 8 | input:col3 as base 9 | 10 | from {{ ref('springbrickstests')}} 11 | where function_name = 'timestampadd' 12 | ), 13 | 14 | test as ( 15 | select input, 16 | expected_output, 17 | {{timestampadd('unit', 'measure', 'base')}} as actual_output, 18 | concat('"',actual_output, '"') as actual_output_quotes 19 | from testraw 20 | 21 | ) 22 | 23 | select * 24 | from test 25 | where expected_output <> actual_output_quotes 26 | -------------------------------------------------------------------------------- /integration_tests/tests/timestampdiff.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | input:col1 as unit, 7 | input:col2 as timeuno, 8 | input:col3 as timedos 9 | 10 | from {{ ref('springbrickstests')}} 11 | where function_name = 'timestampdiff' 12 | ), 13 | 14 | test as ( 15 | select input, 16 | expected_output, 17 | {{timestampdiff('unit', 'timeuno', 'timedos')}} as actual_output 18 | from testraw 19 | 20 | ) 21 | 22 | select * 23 | from test 24 | where expected_output <> actual_output 25 | -------------------------------------------------------------------------------- /macros/.DS_Store: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/techvaquero/lakehouse_utils/c27dc99d14c71498c966fbbea3615a74029eb78e/macros/.DS_Store -------------------------------------------------------------------------------- /macros/redshift/README.md: -------------------------------------------------------------------------------- 1 | #### For the most up to date list of supported functions, refrence the functionlist.csv in the seed directory. 2 | 3 | #### V1 supported functions: 4 | 5 | convert
6 | inputs: type, expression
7 | desc: Like the CAST function, the CONVERT function converts one data type to another compatible data type. For instance, you can convert a string to a date, or a numeric type to a string. CONVERT performs a runtime conversion, which means that the conversion doesn't change a value's data type in a source table. It's changed only in the context of the query.
8 | outputs: CONVERT returns the data type specified by the type argument.
9 | 10 | TEXT_TO_NUMERIC_ALT
11 | inputs: expresssion, format, precision, scale
12 | desc: Amazon Redshift casts the input expression string to the numeric type with the highest precision that you specify for that type in the precision option. If the length of the numeric value exceeds the value that you specify for precision, Amazon Redshift rounds the numeric value according to the following rules:.
13 | 14 | HLL_COMBINE_SKETCHES
15 | inputs: expr1, expr2
16 | desc: The HLL_COMBINE_SKETCHES is a scalar function that takes as input two HLLSKETCH values and combines them into a single HLLSKETCH. 17 | The combination of two or more HyperLogLog sketches is a new HLLSKETCH that encapsulates information about the union of the distinct values that each input sketch represents.
18 | outputs: HLL sketch type
19 | 20 | HLL_COMBINE
21 | inputs: expr
22 | desc: The combination of two or more HyperLogLog sketches is a new HLLSKETCH that encapsulates information about the union of the distinct values that each input sketch represents. After combining sketches, Amazon Redshift extracts the cardinality of the union of two or more datasets.
23 | outputs: HLL sketch type
24 | 25 | HLL_CREATE_SKETCH
26 | inputs: expr1
27 | desc: The HLL_CREATE_SKETCH function returns an HLLSKETCH data type that encapsulates the input expression values. The HLL_CREATE_SKETCH function works with any data type and ignores NULL values. When there are no rows in a table or all rows are NULL, the resulting sketch has no index-value pairs such as {"version":1,"logm":15,"sparse":{"indices":[],"values":[]}}.
28 | outputs: The HLL_CREATE_SKETCH function returns an HLLSKETCH value.
29 | 30 | HLL_CARDINALITY
31 | inputs: expr
32 | desc: The HLL_CARDINALITY function returns the cardinality of the input HLLSKETCH data type.
33 | outputs: BigInt.
34 | 35 | DEXP
36 | inputs: number
37 | desc: The DEXP function returns the exponential value in scientific notation for a double precision number. The only difference between the DEXP and EXP functions is that the parameter for DEXP must be a double precision.
38 | outputs: Double Precision number
39 | 40 | DLOG10
41 | inputs: number
42 | desc: The DLOG10 returns the base 10 logarithm of the input parameter.
43 | outputs: double precision
44 | 45 | DLOG1
46 | inputs: expression
47 | desc: Returns the natural logarithm of the input parameter. Synonym of the DLOG1 function.
48 | outputs: The LN function returns the same type as the expression.
49 | 50 | isnull
51 | inputs: value, value_is_null
52 | desc: ISNULL in Redshift is just like a single COALESCE. This translates to COALESCE(value, value_is_null)
53 | outputs: The LN function returns the same type as the expression.
54 | 55 | getdate
56 | inputs: none
57 | desc: GETDATE returns the current date and time in the current session time zone (UTC by default). It returns the start date or time of the current statement, even when it is within a transaction block.
58 | outputs: The LN function returns the same type as the expression.
59 | 60 | sysdate
61 | inputs: none
62 | desc: SYSDATE returns the current date and time in the current session time zone (UTC by default). 63 | outputs: The LN function returns the same type as the expression.
64 | 65 | #### V1 un-supported functions: 66 | 67 | HLL
68 | inputs: aggregate_expression
69 | desc: The HLL function returns the HyperLogLog cardinality of the input expression values. The HLL function works with any data types except the HLLSKETCH data type. The HLL function ignores NULL values. When there are no rows in a table or all rows are NULL, the resulting cardinality is 0.
70 | outputs: BigInt
71 | why no support: HLL can take in any expression whereas cardinality only takes in array/map expressions 72 | 73 | TEXT_TO_INT_ALT
74 | inputs: expression, format
75 | desc: TEXT_TO_INT_ALT converts a character string to an integer using Teradata-style formatting. Fraction digits in the result are truncated.
76 | outputs: TEXT_TO_INT_ALT returns an INTEGER value.
77 | why no support: incompatible formatting 78 | 79 | -------------------------------------------------------------------------------- /macros/redshift/convert.sql: -------------------------------------------------------------------------------- 1 | {% macro convert(type, expr) %} 2 | cast({{expr}} AS {{type}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/redshift/date_part.sql: -------------------------------------------------------------------------------- 1 | {% macro date_part(unit, expr) %} 2 | CASE 3 | -- Millenia 4 | WHEN lower({{ unit }}::string) IN ('millennium', 'millennia', 'mil', 'mils') THEN (CEILING((YEAR( '{{ expr }}'::timestamp ) - 1) / 1000)) 5 | -- Century 6 | WHEN lower({{ unit }}::string) IN ('century', 'centuries', 'c', 'cent', 'cents') THEN (CEILING((YEAR( '{{ expr }}'::timestamp ) - 1) / 100)) 7 | -- Decade 8 | WHEN lower({{ unit }}::string) IN ('decade', 'decades', 'dec', 'decs') THEN (CEILING((YEAR( '{{ expr }}'::timestamp ) - 1) / 10)) 9 | -- Years 10 | WHEN lower({{ unit }}::string) IN ('year', 'years','y', 'yr', 'yrs') THEN FLOOR(date_part('YEAR', '{{expr}}'::timestamp) / 1) 11 | -- Quarter 12 | WHEN lower({{ unit }}::string) IN ('quarter', 'quarters', 'qtr', 'qtrs') THEN date_part('QUARTER', '{{expr}}'::timestamp) 13 | -- Month 14 | WHEN lower({{ unit }}::string) IN ('month', 'months', 'mon', 'mons') THEN date_part('MONTH', '{{expr}}'::timestamp) 15 | -- Week 16 | WHEN lower({{ unit }}::string) IN ('week', 'weeks', 'w') THEN date_part('WEEK', '{{expr}}'::timestamp) 17 | -- Day of Week: in Redshift day of week is 0-6, starting with Sunday, Databricks is 1-7, starting with Sunday 18 | WHEN lower({{ unit }}::string) IN ('day of week', 'dayofweek', 'dow', 'dw', 'weekday') THEN date_part('DAYOFWEEK', '{{expr}}'::timestamp) - 1 19 | -- Day 20 | WHEN lower({{ unit }}::string) IN ('day', 'days', 'd') THEN date_part('DAY', '{{expr}}'::timestamp) 21 | -- Hour 22 | WHEN lower({{ unit }}::string) IN ('hour', 'hours', 'h', 'hr', 'hrs') THEN date_part('HOUR', '{{expr}}'::timestamp) 23 | -- Minute 24 | WHEN lower({{ unit }}::string) IN ('minute', 'minutes', 'm', 'min', 'mins') THEN date_part('MINUTE', '{{expr}}'::timestamp) 25 | -- Second 26 | WHEN lower({{ unit }}::string) IN ('second', 'seconds', 's', 'sec', 'secs') THEN date_part('SECOND', '{{expr}}'::timestamp) 27 | -- Millisecond 28 | WHEN lower({{ unit }}::string) IN ('millisecond', 'milliseconds', 'ms', 'msec', 'msecs', 'msecond', 'mseconds', 'millisec', 'millisecs', 'millisecon') THEN date_part('SECOND', '{{expr}}'::timestamp)*1000 29 | -- Microsecond 30 | WHEN lower({{ unit }}::string) IN ('microsecond', 'microseconds', 'microsec', 'microsecs', 'microsecond', 'usecond', 'useconds', 'us', 'usec', 'usecs') THEN date_part('SECOND', '{{expr}}'::timestamp)*1000000 31 | -- Else just try to use the raw unit - let it fail if it doenst convert so users know 32 | ELSE NULL 33 | END 34 | 35 | {% endmacro %} 36 | -------------------------------------------------------------------------------- /macros/redshift/date_trunc.sql: -------------------------------------------------------------------------------- 1 | {% macro date_trunc(unit, expr) %} 2 | 3 | CASE 4 | -- Millenia 5 | WHEN lower({{ unit }}::string) IN ('millennium', 'millennia', 'mil', 'mils') THEN CONCAT((1 + FLOOR((YEAR( '{{ expr }}'::timestamp ) - 1) / 1000) * 1000)::string, '-01-01 00:00:00')::timestamp 6 | -- Century 7 | WHEN lower({{ unit }}::string) IN ('century', 'centuries', 'c', 'cent', 'cents') THEN CONCAT((1 + FLOOR((YEAR( '{{ expr }}'::timestamp ) - 1) / 100) * 100)::string, '-01-01 00:00:00')::timestamp 8 | -- Decade 9 | WHEN lower({{ unit }}::string) IN ('decade', 'decades', 'dec', 'decs') THEN CONCAT((1 + FLOOR((YEAR( '{{ expr }}'::timestamp ) - 1) / 10) * 10)::string, '-01-01 00:00:00')::timestamp 10 | -- Years 11 | WHEN lower({{ unit }}::string) IN ('year', 'years','y', 'yr', 'yrs') THEN date_trunc('year', '{{expr}}'::timestamp)::timestamp 12 | -- Quarter 13 | WHEN lower({{ unit }}::string) IN ('quarter', 'quarters', 'qtr', 'qtrs') THEN date_trunc('quarter', '{{expr}}'::timestamp)::timestamp 14 | -- Month 15 | WHEN lower({{ unit }}::string) IN ('month', 'months', 'mon', 'mons') THEN date_trunc('month', '{{expr}}'::timestamp)::timestamp 16 | -- Week 17 | WHEN lower({{ unit }}::string) IN ('week', 'weeks', 'w') THEN date_trunc('week', '{{expr}}'::timestamp)::timestamp 18 | --Day 19 | WHEN lower({{ unit }}::string) IN ('day', 'days', 'd') THEN date_trunc('day', '{{expr}}'::timestamp)::timestamp 20 | -- Hour 21 | WHEN lower({{ unit }}::string) IN ('hour', 'hours', 'h', 'hr', 'hrs') THEN date_trunc('hour', '{{expr}}'::timestamp)::timestamp 22 | -- Minute 23 | WHEN lower({{ unit }}::string) IN ('minute', 'minutes', 'm', 'min', 'mins') THEN date_trunc('minute', '{{expr}}'::timestamp)::timestamp 24 | -- Second 25 | WHEN lower({{ unit }}::string) IN ('second', 'seconds', 's', 'sec', 'secs') THEN date_trunc('second', '{{expr}}'::timestamp)::timestamp 26 | -- Millisecond 27 | WHEN lower({{ unit }}::string) IN ('millisecond', 'milliseconds', 'ms', 'msec', 'msecs', 'msecond', 'mseconds', 'millisec', 'millisecs', 'millisecon') THEN date_trunc('millisecond', '{{expr}}'::timestamp)::timestamp 28 | -- Microsecond 29 | WHEN lower({{ unit }}::string) IN ('microsecond', 'microseconds', 'microsec', 'microsecs', 'microsecond', 'usecond', 'useconds', 'us', 'usec', 'usecs') THEN date_trunc('microsecond', '{{expr}}'::timestamp)::timestamp 30 | -- Else just try to use the raw unit - let it fail if it doenst convert so users know 31 | ELSE NULL 32 | END 33 | 34 | {% endmacro %} 35 | 36 | -------------------------------------------------------------------------------- /macros/redshift/datediff.sql: -------------------------------------------------------------------------------- 1 | {% macro datediff(unit, start, end) %} 2 | CASE 3 | -- Millenia 4 | WHEN lower({{ unit }}::string) IN ('millennium', 'millennia', 'mil', 'mils') THEN FLOOR(timestampdiff(YEAR, '{{start}}'::timestamp, '{{end}}'::timestamp) / 1000) 5 | -- Century 6 | WHEN lower({{ unit }}::string) IN ('century', 'centuries', 'c', 'cent', 'cents') THEN FLOOR(timestampdiff(YEAR, '{{start}}'::timestamp, '{{end}}'::timestamp) / 100) 7 | -- Decade 8 | WHEN lower({{ unit }}::string) IN ('decade', 'decades', 'dec', 'decs') THEN FLOOR(timestampdiff(YEAR, '{{start}}'::timestamp, '{{end}}'::timestamp) / 10) 9 | -- Years 10 | WHEN lower({{ unit }}::string) IN ('year', 'years','y', 'yr', 'yrs') THEN FLOOR(timestampdiff(YEAR, '{{start}}'::timestamp, '{{end}}'::timestamp) / 1) 11 | -- Quarter 12 | WHEN lower({{ unit }}::string) IN ('quarter', 'quarters', 'qtr', 'qtrs') THEN timestampdiff(QUARTER, '{{start}}'::timestamp, '{{end}}'::timestamp) 13 | -- Month 14 | WHEN lower({{ unit }}::string) IN ('month', 'months', 'mon', 'mons') THEN timestampdiff(MONTH, '{{start}}'::timestamp, '{{end}}'::timestamp) 15 | -- Week 16 | WHEN lower({{ unit }}::string) IN ('week', 'weeks', 'w') THEN timestampdiff(WEEK, '{{start}}'::timestamp, '{{end}}'::timestamp) 17 | -- Day 18 | WHEN lower({{ unit }}::string) IN ('day', 'days', 'd') THEN timestampdiff(DAY, '{{start}}'::timestamp, '{{end}}'::timestamp) 19 | -- Hour 20 | WHEN lower({{ unit }}::string) IN ('hour', 'hours', 'h', 'hr', 'hrs') THEN timestampdiff(HOUR, '{{start}}'::timestamp, '{{end}}'::timestamp) 21 | -- Minute 22 | WHEN lower({{ unit }}::string) IN ('minute', 'minutes', 'm', 'min', 'mins') THEN timestampdiff(MINUTE, '{{start}}'::timestamp, '{{end}}'::timestamp) 23 | -- Second 24 | WHEN lower({{ unit }}::string) IN ('second', 'seconds', 's', 'sec', 'secs') THEN timestampdiff(SECOND, '{{start}}'::timestamp, '{{end}}'::timestamp) 25 | -- Millisecond 26 | WHEN lower({{ unit }}::string) IN ('millisecond', 'milliseconds', 'ms', 'msec', 'msecs', 'msecond', 'mseconds', 'millisec', 'millisecs', 'millisecon') THEN timestampdiff(MILLISECOND, '{{start}}'::timestamp, '{{end}}'::timestamp) 27 | -- Microsecond 28 | WHEN lower({{ unit }}::string) IN ('microsecond', 'microseconds', 'microsec', 'microsecs', 'microsecond', 'usecond', 'useconds', 'us', 'usec', 'usecs') THEN timestampdiff(MICROSECOND, '{{start}}'::timestamp, '{{end}}'::timestamp) 29 | -- Else just try to use the raw unit - let it fail if it doenst convert so users know 30 | ELSE NULL 31 | END 32 | {% endmacro %} 33 | -------------------------------------------------------------------------------- /macros/redshift/dexp.sql: -------------------------------------------------------------------------------- 1 | -- macros/dexp.sql 2 | 3 | {% macro dexp(x) %} 4 | POWER(2.71828, {{ x }}) 5 | {% endmacro %} -------------------------------------------------------------------------------- /macros/redshift/dlog1.sql: -------------------------------------------------------------------------------- 1 | {% macro dlog1(expr) %} 2 | ln({{expr}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/redshift/dlog10.sql: -------------------------------------------------------------------------------- 1 | {% macro dlog10(expr) %} 2 | log10({{expr}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/redshift/getdate.sql: -------------------------------------------------------------------------------- 1 | {% macro redshift_getdate() %} 2 | date_format(date_trunc('second', current_timestamp()), 'yyyy-MM-dd HH:mm:ss') 3 | {% endmacro %} -------------------------------------------------------------------------------- /macros/redshift/hll.sql: -------------------------------------------------------------------------------- 1 | {% macro hll(expr) %} 2 | cardinality({{expr}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/redshift/hll_cardinality.sql: -------------------------------------------------------------------------------- 1 | {% macro hll_cardinality(expr) %} 2 | hll_sketch_estimate({{expr}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/redshift/hll_combine.sql: -------------------------------------------------------------------------------- 1 | {% macro hll_combine(expr) %} 2 | hll_union_agg({{expr}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/redshift/hll_combine_skeetches.sql: -------------------------------------------------------------------------------- 1 | {% macro hll_combine_sketches(expr1, expr2) %} 2 | hll_union({{expr1}}, {{expr2}} ) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/redshift/hll_create_sketch .sql: -------------------------------------------------------------------------------- 1 | {% macro hll_create_sketch(expr) %} 2 | hll_sketch_agg({{expr}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/redshift/isnull.sql: -------------------------------------------------------------------------------- 1 | {% macro isnull(value, if_null_value) %} 2 | coalesce(value, if_null_value) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/redshift/strtol.sql: -------------------------------------------------------------------------------- 1 | {% macro strtol(num, frombase) %} 2 | conv({{num}}, {{frombase}}, 10) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/redshift/sysdate.sql: -------------------------------------------------------------------------------- 1 | {% macro redshift_sysdate() %} 2 | date_format(current_timestamp(), 'yyyy-MM-dd HH:mm:ss') 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/redshift/texttointalt.sql: -------------------------------------------------------------------------------- 1 | -- macros/texttointalt.sql 2 | 3 | {% macro texttointalt(input_expression, format_phrase) %} 4 | 5 | SELECT 6 | {{ input_expression }} as original_input, 7 | {{ format_phrase }} AS format_phrase, 8 | 9 | CASE 10 | -- Handle format: '999S' 11 | WHEN {{ format_phrase }} = '999S' THEN 12 | CAST(REGEXP_REPLACE({{ input_expression }}, '[^0-9]', '') AS INT) 13 | 14 | -- Handle format: 'C9(I)' 15 | WHEN {{ format_phrase }} = 'C9(I)' THEN 16 | CAST( 17 | CASE 18 | WHEN REGEXP_REPLACE({{ input_expression }}, '[^0-9]', '') LIKE '%-%' 19 | THEN '-' || REGEXP_REPLACE(REGEXP_REPLACE({{ input_expression }}, '[^0-9]', ''), '\\D', '') 20 | ELSE REGEXP_REPLACE({{ input_expression }}, '[^0-9]', '') 21 | END AS INT 22 | ) 23 | 24 | -- Handle exponential format: '-123E-2' 25 | WHEN {{ format_phrase }} IS NULL AND REGEXP_MATCH({{ input_expression }}, '[-+]?\d+(?:\.\d+)?(?:[eE][-+]?\d+)?') IS NOT NULL THEN 26 | CAST( 27 | CASE 28 | WHEN {{ input_expression }} LIKE '%-%' 29 | THEN '-' || CAST(CAST({{ input_expression }} AS FLOAT) AS INT) 30 | ELSE CAST(CAST({{ input_expression }} AS FLOAT) AS INT) 31 | END AS INT 32 | ) 33 | 34 | -- Handle input expression ending with a hyphen 35 | WHEN {{ format_phrase }} IS NULL AND {{ input_expression }} LIKE '%-' THEN 36 | CAST('-' || REGEXP_REPLACE({{ input_expression }}, '[^0-9-]', '') AS INT) 37 | 38 | -- Handle positive integer 39 | WHEN {{ format_phrase }} IS NULL AND REGEXP_MATCH({{ input_expression }}, '^\d+$') IS NOT NULL THEN 40 | CAST({{ input_expression }} AS INT) 41 | 42 | ELSE NULL 43 | END AS texttointalt 44 | {% endmacro %} -------------------------------------------------------------------------------- /macros/redshift/texttonumericalt.sql: -------------------------------------------------------------------------------- 1 | {% macro texttonumericalt(expr, format, precision, scale) %} 2 | 3 | 4 | {% if scale %} 5 | 6 | 7 | 8 | 9 | cast({{expr}} as decimal({{precision}}, {{scale}})) 10 | 11 | 12 | {% elif precision %} 13 | 14 | cast({{expr}} as decimal({{format}}, {{precision}})) 15 | 16 | 17 | {% elif format %} 18 | 19 | to_number({{expr}}, "{{format}}") 20 | 21 | 22 | {% else %} 23 | 24 | cast({{expr}} as decimal(38, 0)) 25 | 26 | {% endif %} 27 | 28 | {% endmacro %} 29 | -------------------------------------------------------------------------------- /macros/snowflake/array_agg.sql: -------------------------------------------------------------------------------- 1 | {% macro array_agg(arg, delim) %} 2 | CASE WHEN locate('distinct', lower({{arg}})) = 0 3 | THEN sort_array(collect_list({{arg}}), {{delim}}) 4 | ELSE sort_array(collect_list(DISTINCT {{arg}}), {{delim}}) 5 | END 6 | {% endmacro %} 7 | -------------------------------------------------------------------------------- /macros/snowflake/array_cat.sql: -------------------------------------------------------------------------------- 1 | {% macro array_cat(arg1, arg2) %} 2 | concat({{arg1}}, {{arg2}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/array_compact.sql: -------------------------------------------------------------------------------- 1 | {% macro array_compact(arg) %} 2 | filter({{arg}} , x -> x IS NOT NULL) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/array_construct.sql: -------------------------------------------------------------------------------- 1 | {% macro array_construct(expr) %} 2 | array({{expr}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/array_intersection.sql: -------------------------------------------------------------------------------- 1 | {% macro array_intersection(arg1, arg2) %} 2 | array_intersect({{arg1}}, {{arg2}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/array_size.sql: -------------------------------------------------------------------------------- 1 | {% macro array_size(column_name) %} 2 | size({{column_name}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/array_slice.sql: -------------------------------------------------------------------------------- 1 | {% macro array_slice(arg1, arg2, arg3) %} 2 | slice({{arg1}}, {{arg2}}, ({{arg3}} - {{arg2}})) 3 | {% endmacro %} -------------------------------------------------------------------------------- /macros/snowflake/array_to_string.sql: -------------------------------------------------------------------------------- 1 | {% macro array_to_string(arg, delim) %} 2 | array_join({{arg}}, {{delim}}, null) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/base64_decode_binary.sql: -------------------------------------------------------------------------------- 1 | {% macro base64_decode_binary(arg) %} 2 | unbase64({{arg}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/base64_decode_string.sql: -------------------------------------------------------------------------------- 1 | {% macro base64_decode_string(arg) %} 2 | unbase({{arg}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/base64_encode.sql: -------------------------------------------------------------------------------- 1 | {% macro base64_encode(arg) %} 2 | base64({{arg}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/bitand.sql: -------------------------------------------------------------------------------- 1 | {% macro bitand(arg1, arg2) %} 2 | {{arg1}} & {{arg2}} 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/booland_agg.sql: -------------------------------------------------------------------------------- 1 | {% macro booland_agg(arg1) %} 2 | bool_and({{arg1}}) 3 | {% endmacro %} -------------------------------------------------------------------------------- /macros/snowflake/boolor_agg.sql: -------------------------------------------------------------------------------- 1 | {% macro boolor_agg(arg1) %} 2 | bool_or({{arg1}}) 3 | {% endmacro %} -------------------------------------------------------------------------------- /macros/snowflake/charindex.sql: -------------------------------------------------------------------------------- 1 | {% macro charindex(arg1, arg2, start) %} 2 | position({{arg1}}, {{arg2}}, {{start}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/contains.sql: -------------------------------------------------------------------------------- 1 | {% macro contains(column_name, position) %} 2 | 3 | charindex({{position}}, {{column_name}}) > 0 4 | 5 | {% endmacro %} 6 | -------------------------------------------------------------------------------- /macros/snowflake/current_schema.sql: -------------------------------------------------------------------------------- 1 | {% macro current_schema() %} 2 | current_database() 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/date_from_parts.sql: -------------------------------------------------------------------------------- 1 | {% macro date_from_parts(year, month, day) %} 2 | make_date({{year}}, {{month}}, {{day}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/dateaddog.sql: -------------------------------------------------------------------------------- 1 | {% macro dateadd(unit, measure, base) %} 2 | CASE 3 | WHEN lower({{unit}}) = 'year' THEN {{base}} + make_interval({{measure}}) 4 | WHEN lower({{unit}}) = 'month' THEN {{base}} + make_interval(0, {{measure}}) 5 | WHEN lower({{unit}}) = 'day' THEN {{base}} + make_interval(0, 0, 0, {{measure}}) 6 | WHEN lower({{unit}}) = 'hour' THEN {{base}} + make_interval(0, 0, 0, 0, {{measure}}) 7 | WHEN lower({{unit}}) = 'minute' THEN {{base}} + make_interval(0, 0, 0, 0, 0, {{measure}}) 8 | WHEN lower({{unit}}) = 'second' THEN {{base}} + make_interval(0, 0, 0, 0, 0, 0, {{measure}}) 9 | END 10 | {% endmacro %} 11 | -------------------------------------------------------------------------------- /macros/snowflake/dayname.sql: -------------------------------------------------------------------------------- 1 | {% macro dayname(arg) %} 2 | CASE 3 | WHEN datediff(CAST({{arg}} AS DATE), DATE'1799-12-29') % 7 = 0 THEN 'Sun' 4 | WHEN datediff(CAST({{arg}} AS DATE), DATE'1799-12-29') % 7 = 1 THEN 'Mon' 5 | WHEN datediff(CAST({{arg}} AS DATE), DATE'1799-12-29') % 7 = 2 THEN 'Tue' 6 | WHEN datediff(CAST({{arg}} AS DATE), DATE'1799-12-29') % 7 = 3 THEN 'Wed' 7 | WHEN datediff(CAST({{arg}} AS DATE), DATE'1799-12-29') % 7 = 4 THEN 'Thu' 8 | WHEN datediff(CAST({{arg}} AS DATE), DATE'1799-12-29') % 7 = 5 THEN 'Fri' 9 | ELSE 'Sat' END 10 | {% endmacro %} 11 | -------------------------------------------------------------------------------- /macros/snowflake/dayofweekiso.sql: -------------------------------------------------------------------------------- 1 | {% macro dayofweekiso(arg) %} 2 | EXTRACT(DAYOFWEEK_ISO FROM {{arg}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/dbt_housekeeping.sql: -------------------------------------------------------------------------------- 1 | {% macro dbt_housekeeping() -%} 2 | '{{ invocation_id }}'::string as dbt_batch_id, 3 | '{{ run_started_at }}'::timestamp as dbt_batch_ts 4 | {%- endmacro %} 5 | -------------------------------------------------------------------------------- /macros/snowflake/div0.sql: -------------------------------------------------------------------------------- 1 | {% macro div0(arg1, arg2) %} 2 | CASE WHEN {{arg2}} = 0 THEN 0 ELSE {{arg1}} / {{arg2}} END; 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/dt_convert_money.sql: -------------------------------------------------------------------------------- 1 | {% macro money(col) -%} 2 | ::decimal(16,4) 3 | {%- endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/endswith.sql: -------------------------------------------------------------------------------- 1 | {% macro endswith(arg1, arg2) %} 2 | substr({{arg1}}, -length({{arg2}}), length({{arg2}})) = {{arg2}}; 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/equal_null.sql: -------------------------------------------------------------------------------- 1 | {% macro equal_null(arg1, arg2) %} 2 | {{arg1}} <=> {{arg2}} 3 | {% endmacro %} -------------------------------------------------------------------------------- /macros/snowflake/exclude.sql: -------------------------------------------------------------------------------- 1 | {%- macro exclude() -%} 2 | 3 | {%- set all_args = [] -%} 4 | {% for col in kwargs.items() -%} 5 | {%- do all_args.append(col) -%} 6 | {%- endfor -%} 7 | 8 | 9 | except({{ all_args|join(', ') }}) 10 | {%- endmacro -%} 11 | -------------------------------------------------------------------------------- /macros/snowflake/from_utc_timestamp.sql: -------------------------------------------------------------------------------- 1 | {% macro from_utc_timestamp(source, target, stamp) %} 2 | from_utc_timestamp(to_utc_timestamp({{stamp}}, {{source}}), {{target}}) 3 | {% endmacro %} -------------------------------------------------------------------------------- /macros/snowflake/getdate.sql: -------------------------------------------------------------------------------- 1 | {% macro getdate() %} 2 | current_timestamp() 3 | {% endmacro %} -------------------------------------------------------------------------------- /macros/snowflake/hex_decode_string.sql: -------------------------------------------------------------------------------- 1 | {% macro hex_decode_string(arg1) %} 2 | decode(unhex({{arg1}}), 'UTF-8') 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/hll_estimate.sql: -------------------------------------------------------------------------------- 1 | {% macro hll_estimate(expr) %} 2 | hll_sketch_estimate({{expr}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/insert.sql: -------------------------------------------------------------------------------- 1 | {% macro insert(base, pos, len, ins) %} 2 | overlay({{base}}, {{ins}}, {{pos}}, {{len}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/is_null_value.sql: -------------------------------------------------------------------------------- 1 | {% macro is_null_value(string) %} 2 | isnull({{string}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/json_extract_path_text.sql: -------------------------------------------------------------------------------- 1 | {% macro json_extract_path_text(expr, key) %} 2 | get_json_object({{expr}}, '$.{{key}}') 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/listagg.sql: -------------------------------------------------------------------------------- 1 | {% macro listagg(arg, delim) %} 2 | array_join(sort_array(collect_list({{arg}})), "{{delim}}") 3 | 4 | {% endmacro %} -------------------------------------------------------------------------------- /macros/snowflake/md5_binary.sql: -------------------------------------------------------------------------------- 1 | {% macro md5_binary(arg) %} 2 | md5({{arg}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/monthname.sql: -------------------------------------------------------------------------------- 1 | {% macro monthname(arg) %} 2 | CASE 3 | WHEN EXTRACT(MONTH FROM {{arg}}) = 1 THEN 'Jan' 4 | WHEN EXTRACT(MONTH FROM {{arg}}) = 2 THEN 'Feb' 5 | WHEN EXTRACT(MONTH FROM {{arg}}) = 3 THEN 'Mar' 6 | WHEN EXTRACT(MONTH FROM {{arg}}) = 4 THEN 'Apr' 7 | WHEN EXTRACT(MONTH FROM {{arg}}) = 5 THEN 'May' 8 | WHEN EXTRACT(MONTH FROM {{arg}}) = 6 THEN 'Jun' 9 | WHEN EXTRACT(MONTH FROM {{arg}}) = 7 THEN 'Jul' 10 | WHEN EXTRACT(MONTH FROM {{arg}}) = 8 THEN 'Aug' 11 | WHEN EXTRACT(MONTH FROM {{arg}}) = 9 THEN 'Sep' 12 | WHEN EXTRACT(MONTH FROM {{arg}}) = 10 THEN 'Oct' 13 | WHEN EXTRACT(MONTH FROM {{arg}}) = 11 THEN 'Nov' 14 | ELSE 'Dec' END 15 | {% endmacro %} 16 | -------------------------------------------------------------------------------- /macros/snowflake/nullifzero.sql: -------------------------------------------------------------------------------- 1 | {% macro nullifzero(arg) %} 2 | nullif({{arg}}, 0) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/parse_json.sql: -------------------------------------------------------------------------------- 1 | {% macro parse_json(string) %} 2 | from_json({{string}}, schema_of_json({{string}})) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/previous_day.sql: -------------------------------------------------------------------------------- 1 | {% macro previous_day(arg, day) %} 2 | CASE WHEN substr(dayname({{arg}}), 1, 2) = substr({{day}}, 1, 2) THEN {{arg}} - INTERVAL 7 DAY 3 | ELSE next_day({{arg}}, {{day}}) - INTERVAL 7 DAY END; 4 | {% endmacro %} 5 | -------------------------------------------------------------------------------- /macros/snowflake/seq1.sql: -------------------------------------------------------------------------------- 1 | {% macro seq1() %} 2 | monotonically_increasing_id() 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/seq2.sql: -------------------------------------------------------------------------------- 1 | {% macro seq2(arg) %} 2 | monotonically_increasing_id() 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/seq4.sql: -------------------------------------------------------------------------------- 1 | {% macro seq4() %} 2 | monotonically_increasing_id() 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/seq8.sql: -------------------------------------------------------------------------------- 1 | {% macro seq8() %} 2 | monotonically_increasing_id() 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/sha1hex.sql: -------------------------------------------------------------------------------- 1 | {% macro sha1hex(arg, len) %} 2 | sha1({{arg}}, {{len}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/sha2_hex.sql: -------------------------------------------------------------------------------- 1 | {% macro sha2_hex(arg, len) %} 2 | sha2({{arg}}, {{len}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/split_part.sql: -------------------------------------------------------------------------------- 1 | {% macro split_part(arg, delim, part) %} 2 | element_at(split({{arg}}, {{delim}}), {{part}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/square.sql: -------------------------------------------------------------------------------- 1 | {% macro square(arg) %} 2 | {{arg}} * {{arg}} 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/startswith.sql: -------------------------------------------------------------------------------- 1 | {% macro startswith(arg1, arg2) %} 2 | position({{arg2}}, {{arg1}}) = 1 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/strtok.sql: -------------------------------------------------------------------------------- 1 | {% macro strtok(arg, delim, part) %} 2 | element_at(split({{arg}}, {{delim}}), {{part}} ) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/strtok_to_array.sql: -------------------------------------------------------------------------------- 1 | {% macro strtok_to_array(arg, delim) %} 2 | split({{arg}}, concat("[", {{delim}}, "]")) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/sysdate.sql: -------------------------------------------------------------------------------- 1 | {% macro sysdate() %} 2 | to_utc_timestamp(current_timestamp(), current_timezone()); 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/systimestamp.sql: -------------------------------------------------------------------------------- 1 | {% macro systimestamp() %} 2 | current_timestamp() 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/timediff.sql: -------------------------------------------------------------------------------- 1 | {% macro timediff(unit, arg1,arg2) %} 2 | CASE 3 | WHEN lower({{unit}}) = 'year' THEN EXTRACT(YEAR FROM {{arg2}}) - EXTRACT(YEAR FROM {{arg1}}) 4 | WHEN lower({{unit}}) = 'month' THEN (EXTRACT(YEAR FROM {{arg2}}) * 12 + EXTRACT(MONTH FROM {{arg2}})) 5 | - (EXTRACT(YEAR FROM {{arg1}}) * 12 + EXTRACT(MONTH FROM {{arg1}})) 6 | WHEN lower({{unit}}) = 'day' THEN datediff(CAST({{arg2}} AS DATE), CAST({{arg1}} AS DATE)) 7 | WHEN lower({{unit}}) = 'hour' THEN EXTRACT(HOUR FROM {{arg2}}) - EXTRACT(HOUR FROM {{arg1}}) 8 | WHEN lower({{unit}}) = 'minute' THEN (EXTRACT(HOUR FROM {{arg2}}) * 60 + EXTRACT(MINUTE FROM {{arg2}})) 9 | - (EXTRACT(HOURs FROM {{arg1}}) * 60 + EXTRACT(MINUTE FROM {{arg1}})) 10 | WHEN lower({{unit}}) = 'second' THEN (EXTRACT(HOUR FROM {{arg2}}) * 3600 + EXTRACT(MINUTE FROM {{arg2}}) * 60 + EXTRACT(SECOND FROM {{arg2}})) 11 | - (EXTRACT(HOUR FROM {{arg2}}) * 3600 + EXTRACT(MINUTE FROM {{arg2}}) * 60 + EXTRACT(SECOND FROM {{arg2}})) 12 | END 13 | {% endmacro %} 14 | -------------------------------------------------------------------------------- /macros/snowflake/timestamp_from_parts.sql: -------------------------------------------------------------------------------- 1 | {% macro timestamp_from_parts(year, month, day, hour, minute, second) %} 2 | make_timestamp({{year}}, {{month}}, {{day}}, {{hour}}, {{minute}}, {{second}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/timestamp_ntz_from_parts.sql: -------------------------------------------------------------------------------- 1 | {% macro timestamp_ntz_from_parts(year, month, day, hour, minute, second) %} 2 | cast(make_timestamp({{year}}, {{month}}, {{day}}, {{hour}}, {{minute}}, {{second}}) as timestamp_ntz) 3 | {% endmacro %} -------------------------------------------------------------------------------- /macros/snowflake/timestampadd.sql: -------------------------------------------------------------------------------- 1 | {% macro timestampadd(unit, measure, base) %} 2 | CASE 3 | WHEN lower({{unit}}) = 'year' THEN {{base}} + make_interval({{measure}}) 4 | WHEN lower({{unit}}) = 'month' THEN {{base}} + make_interval(0, {{measure}}) 5 | WHEN lower({{unit}}) = 'day' THEN {{base}} + make_interval(0, 0, 0, {{measure}}) 6 | WHEN lower({{unit}}) = 'hour' THEN {{base}} + make_interval(0, 0, 0, 0, {{measure}}) 7 | WHEN lower({{unit}}) = 'minute' THEN {{base}} + make_interval(0, 0, 0, 0, 0, {{measure}}) 8 | WHEN lower({{unit}}) = 'second' THEN {{base}} + make_interval(0, 0, 0, 0, 0, 0, {{measure}}) 9 | END 10 | {% endmacro %} 11 | -------------------------------------------------------------------------------- /macros/snowflake/timestampdiff.sql: -------------------------------------------------------------------------------- 1 | {% macro timestampdiff(unit, arg1,arg2) %} 2 | CASE 3 | WHEN lower({{unit}}) = 'year' THEN EXTRACT(YEAR FROM {{arg2}}) - EXTRACT(YEAR FROM {{arg1}}) 4 | WHEN lower({{unit}}) = 'month' THEN (EXTRACT(YEAR FROM {{arg2}}) * 12 + EXTRACT(MONTH FROM {{arg2}})) 5 | - (EXTRACT(YEAR FROM {{arg1}}) * 12 + EXTRACT(MONTH FROM {{arg1}})) 6 | WHEN lower({{unit}}) = 'day' THEN datediff(CAST({{arg2}} AS DATE), CAST({{arg1}} AS DATE)) 7 | WHEN lower({{unit}}) = 'hour' THEN EXTRACT(HOUR FROM {{arg2}}) - EXTRACT(HOUR FROM {{arg1}}) 8 | WHEN lower({{unit}}) = 'minute' THEN (EXTRACT(HOUR FROM {{arg2}}) * 60 + EXTRACT(MINUTE FROM {{arg2}})) 9 | - (EXTRACT(HOUR FROM {{arg1}}) * 60 + EXTRACT(MINUTE FROM {{arg1}})) 10 | WHEN lower({{unit}}) = 'second' THEN (EXTRACT(HOUR FROM {{arg2}}) * 3600 + EXTRACT(MINUTE FROM {{arg2}}) * 60 + EXTRACT(SECOND FROM {{arg2}})) 11 | - (EXTRACT(HOUR FROM {{arg2}}) * 3600 + EXTRACT(MINUTE FROM {{arg2}}) * 60 + EXTRACT(SECOND FROM {{arg2}})) 12 | END 13 | {% endmacro %} 14 | -------------------------------------------------------------------------------- /macros/snowflake/to_array.sql: -------------------------------------------------------------------------------- 1 | {% macro to_array(expr) %} 2 | array({{expr}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/to_binary.sql: -------------------------------------------------------------------------------- 1 | {% macro to_binary(arg) %} 2 | unhex({{arg}}) 3 | {% endmacro %} -------------------------------------------------------------------------------- /macros/snowflake/to_boolean.sql: -------------------------------------------------------------------------------- 1 | {% macro to_boolean(arg) %} 2 | CASE 3 | WHEN lower({{arg}}) = 'false' THEN FALSE 4 | WHEN lower({{arg}}) = 'f' THEN FALSE 5 | WHEN lower({{arg}}) = 'no' THEN FALSE 6 | WHEN lower({{arg}}) = 'n' THEN FALSE 7 | WHEN lower({{arg}}) = 'off' THEN FALSE 8 | WHEN lower({{arg}}) = '0' THEN FALSE 9 | WHEN lower({{arg}}) = 'true' THEN TRUE 10 | WHEN lower({{arg}}) = 't' THEN TRUE 11 | WHEN lower({{arg}}) = 'yes' THEN TRUE 12 | WHEN lower({{arg}}) = 'y' THEN TRUE 13 | WHEN lower({{arg}}) = 'on' THEN TRUE 14 | WHEN lower({{arg}}) = '1' THEN TRUE 15 | 16 | ELSE NULL 17 | END 18 | {% endmacro %} 19 | -------------------------------------------------------------------------------- /macros/snowflake/to_char.sql: -------------------------------------------------------------------------------- 1 | {% macro to_char(arg) %} 2 | cast({{arg}} as string) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/to_decimal.sql: -------------------------------------------------------------------------------- 1 | {% macro to_decimal(expr, format, precision, scale) %} 2 | 3 | 4 | {% if scale %} 5 | 6 | 7 | 8 | 9 | cast({{expr}} as decimal({{precision}}, {{scale}})) 10 | 11 | 12 | {% elif precision %} 13 | 14 | cast({{expr}} as decimal({{format}}, {{precision}})) 15 | 16 | 17 | {% elif format %} 18 | 19 | to_number({{expr}}, "{{format}}") 20 | 21 | 22 | {% else %} 23 | 24 | cast({{expr}} as decimal(38, 0)) 25 | 26 | {% endif %} 27 | 28 | {% endmacro %} 29 | -------------------------------------------------------------------------------- /macros/snowflake/to_number.sql: -------------------------------------------------------------------------------- 1 | {% macro to_number(expr, format, precision, scale) %} 2 | 3 | 4 | {% if scale %} 5 | 6 | 7 | 8 | 9 | cast({{expr}} as decimal({{precision}}, {{scale}})) 10 | 11 | 12 | {% elif precision %} 13 | 14 | cast({{expr}} as decimal({{format}}, {{precision}})) 15 | 16 | 17 | {% elif format %} 18 | 19 | to_number({{expr}}, "{{format}}") 20 | 21 | 22 | {% else %} 23 | 24 | cast({{expr}} as decimal(38, 0)) 25 | 26 | {% endif %} 27 | 28 | {% endmacro %} 29 | -------------------------------------------------------------------------------- /macros/snowflake/to_numeric.sql: -------------------------------------------------------------------------------- 1 | {% macro to_numeric(expr, format, precision, scale) %} 2 | 3 | 4 | {% if scale %} 5 | 6 | 7 | 8 | 9 | cast({{expr}} as decimal({{precision}}, {{scale}})) 10 | 11 | 12 | {% elif precision %} 13 | 14 | cast({{expr}} as decimal({{format}}, {{precision}})) 15 | 16 | 17 | {% elif format %} 18 | 19 | to_number({{expr}}, "{{format}}") 20 | 21 | 22 | {% else %} 23 | 24 | cast({{expr}} as decimal(38, 0)) 25 | 26 | {% endif %} 27 | 28 | {% endmacro %} 29 | -------------------------------------------------------------------------------- /macros/snowflake/to_time.sql: -------------------------------------------------------------------------------- 1 | {% macro to_time(expr) %} 2 | to_timestamp(expr, 'HH:mm:ss') 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/to_timestamp_ntz.sql: -------------------------------------------------------------------------------- 1 | {% macro to_timestamp_ntz(arg) %} 2 | to_timestamp(arg) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/to_varchar.sql: -------------------------------------------------------------------------------- 1 | {% macro to_varchar(expr, format) %} 2 | 3 | {% if format %} 4 | 5 | case when typeof({{expr}}) = 'date' 6 | then to_date({{expr}}, {{format}})::string 7 | when typeof({{expr}}) = 'timestamp' 8 | then to_timestamp({{expr}}, {{format}})::string 9 | when typeof({{expr}}) = 'binary' 10 | then to_binary({{expr}}, {{format}})::string 11 | else to_char({{expr}}, {{format}})::string 12 | end 13 | 14 | {% else %} 15 | 16 | cast({{expr}} as string) 17 | 18 | 19 | 20 | {% endif %} 21 | 22 | {% endmacro %} 23 | -------------------------------------------------------------------------------- /macros/snowflake/try_cast.sql: -------------------------------------------------------------------------------- 1 | {% macro try_cast(column_name, precision=2) %} 2 | cast({{column_name}} as string) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/try_to_decimal.sql: -------------------------------------------------------------------------------- 1 | {% macro try_to_decimal(expr, format, precision, scale) %} 2 | 3 | 4 | {% if scale %} 5 | 6 | 7 | 8 | 9 | try_cast({{expr}} as decimal({{precision}}, {{scale}})) 10 | 11 | 12 | {% elif precision %} 13 | 14 | try_cast({{expr}} as decimal({{format}}, {{precision}})) 15 | 16 | 17 | {% elif format %} 18 | 19 | try_to_number({{expr}}, "{{format}}") 20 | 21 | 22 | {% else %} 23 | 24 | try_cast({{expr}} as decimal(38, 0)) 25 | 26 | {% endif %} 27 | 28 | {% endmacro %} 29 | -------------------------------------------------------------------------------- /macros/snowflake/try_to_number.sql: -------------------------------------------------------------------------------- 1 | {% macro try_to_number(expr, format, precision, scale) %} 2 | 3 | 4 | {% if scale %} 5 | 6 | 7 | 8 | 9 | try_cast({{expr}} as decimal({{precision}}, {{scale}})) 10 | 11 | 12 | {% elif precision %} 13 | 14 | try_cast({{expr}} as decimal({{format}}, {{precision}})) 15 | 16 | 17 | {% elif format %} 18 | 19 | try_to_number({{expr}}, "{{format}}") 20 | 21 | 22 | {% else %} 23 | 24 | try_cast({{expr}} as decimal(38, 0)) 25 | 26 | {% endif %} 27 | 28 | {% endmacro %} 29 | -------------------------------------------------------------------------------- /macros/snowflake/try_to_numeric.sql: -------------------------------------------------------------------------------- 1 | {% macro try_to_numeric(expr, format, precision, scale) %} 2 | 3 | 4 | {% if scale %} 5 | 6 | 7 | 8 | 9 | try_cast({{expr}} as decimal({{precision}}, {{scale}})) 10 | 11 | 12 | {% elif precision %} 13 | 14 | try_cast({{expr}} as decimal({{format}}, {{precision}})) 15 | 16 | 17 | {% elif format %} 18 | 19 | try_to_number({{expr}}, "{{format}}") 20 | 21 | 22 | {% else %} 23 | 24 | try_cast({{expr}} as decimal(38, 0)) 25 | 26 | {% endif %} 27 | 28 | {% endmacro %} 29 | -------------------------------------------------------------------------------- /macros/snowflake/uniform.sql: -------------------------------------------------------------------------------- 1 | {% macro uniform(min, max, double) %} 2 | {{min}} + ({{max}} - {{min}}) * {{rand}} 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/uuid_string.sql: -------------------------------------------------------------------------------- 1 | {% macro uuid_string() %} 2 | uuid() 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/variance_samp.sql: -------------------------------------------------------------------------------- 1 | {% macro variance_samp(arg1) %} 2 | var_samp({{arg1}}) 3 | {% endmacro %} -------------------------------------------------------------------------------- /macros/snowflake/week.sql: -------------------------------------------------------------------------------- 1 | {% macro week(stamp) %} 2 | EXTRACT(WEEK FROM {{stamp}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/weekiso.sql: -------------------------------------------------------------------------------- 1 | {% macro weekiso(arg) %} 2 | extract (week from {{arg}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/yearofweek.sql: -------------------------------------------------------------------------------- 1 | {% macro yearofweek(arg) %} 2 | extract(year from {{arg}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/yearofweekiso.sql: -------------------------------------------------------------------------------- 1 | {% macro yearofweekiso(arg) %} 2 | extract(year from {{arg}}) 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /macros/snowflake/zeroifnull.sql: -------------------------------------------------------------------------------- 1 | {% macro zeroifnull(column_name) %} 2 | nvl({{column_name}}, 0) 3 | {% endmacro %} -------------------------------------------------------------------------------- /models/redshift/customerrs.sql: -------------------------------------------------------------------------------- 1 | 2 | {{ 3 | config( 4 | materialized = 'table' 5 | ) 6 | }} 7 | 8 | select 9 | convert(string,c_custkey) as stringkey, 10 | c_name, 11 | c_address, 12 | c_nationkey, 13 | c_phone, 14 | (to_char(date_trunc('month', getdate()), 'YYYY-MM')) as month, 15 | datediff(days, getdate(), getdate()) as days_since_oldest_unpaid_due_date, 16 | datediff(hours, getdate(), getdate()) as days_since_oldest_unpaid_due_date 17 | date_trunc('months', getdate()), 18 | date_trunc('hours', getdate()), 19 | dateadd(day, -1, getdate()), 20 | case when 'organictest' ~ 'organic|email' then 'match' else 'no match' end as regexmatch, 21 | case when 'organictest' !~ 'organic|email' then 'antimatch' else 'antino match' end as antiregexmatch 22 | dlog10(c_acctbal) as actbalbaseten, 23 | dlog10(c_acctbal) as actbalbaseten, 24 | JSON_EXTRACT_PATH_TEXT('{"f2":{"f3":1},"f4":{"f5":99,"f6":"star"}}','f4', 'f6'), 25 | JSON_EXTRACT_PATH_TEXT(NULLIF(REPLACE(REPLACE( REPLACE(related_videos, '\\', ''), '"{', ''), '}"', ''), ''), 'id') 26 | dexp(100), 27 | date_part(dow, 2008-01-05 14:00:00), 28 | hll_cardinality(expr), 29 | JSON_ARRAY_LENGTH('[11,12,13,{"f1":21,"f2":[25,26]},14]'), 30 | c_mktsegment, 31 | c_comment, 32 | getdate() as hoy, 33 | GETDATE AS get_date_caps_test, 34 | sysdate() AS sys_date_col_test, 35 | SYSDATE() AS sys_date_caps_col_test, 36 | Name, 37 | Age, 38 | CAST(ID AS TEXT) as id_text, 39 | created_date::TIME, 40 | CAST(file_dump AS NUMERIC) as file_dump_numeric, 41 | COALESCE(col1::FLOAT,col2::FLOAT8,col3::INT2) AS xyz 42 | FROM catalog.schema.table1 43 | WHERE colA = colB::CHAR 44 | AND somethingelse = 1 45 | ISNULL(test, test_is_null) AS null_test_col_caps, 46 | ISNULL(test, test_is_null) AS null_test_col_caps, 47 | isnull(test, 'test_is_null') AS null_test_col, 48 | date_part(year, date(origination_date)) || '-' || 'Q' || floor( 49 | (date_part(month, date(origination_date)) - 1) / 3) + 1 as origination_quarter, 50 | date_part(SECONDS, '2019-10-01 00:00:01.000001'::timestamp), 51 | first_value( 52 | case when colA = 2 then id2 53 | end ignore nulls 54 | ) over ( 55 | partition by 56 | customer_id 57 | order by 58 | created_at 59 | rows between unbounded preceding and unbounded following 60 | ) as test_syntax_change 61 | from 62 | redshift_sample_data.tpch_rs1.customer 63 | ORDER BY colC,colB DESC -------------------------------------------------------------------------------- /models/redshift/r1/customerrs.sql: -------------------------------------------------------------------------------- 1 | 2 | {{ 3 | config( 4 | materialized = 'table' 5 | ) 6 | }} 7 | 8 | select 9 | convert(string,c_custkey) as stringkey, 10 | c_name, 11 | c_address, 12 | c_nationkey, 13 | c_phone, 14 | (to_char(date_trunc('month', getdate()), 'YYYY-MM')) as month, 15 | datediff(days, getdate(), getdate()) as days_since_oldest_unpaid_due_date, 16 | date_trunc('months', getdate()), 17 | dateadd('day', -1, getdate()), 18 | case when 'organictest' ~ 'organic|email' then 'match' else 'no match' end as regexmatch, 19 | case when 'organictest' !~ 'organic|email' then 'antimatch' else 'antino match' end as antiregexmatch 20 | dlog10(c_acctbal) as actbalbaseten, 21 | dlog10(c_acctbal) as actbalbaseten, 22 | JSON_EXTRACT_PATH_TEXT('{"f2":{"f3":1},"f4":{"f5":99,"f6":"star"}}','f4', 'f6'), 23 | dexp(100), 24 | date_part(dow, 2008-01-05 14:00:00), 25 | hll_cardinality(expr), 26 | JSON_ARRAY_LENGTH('[11,12,13,{"f1":21,"f2":[25,26]},14]'), 27 | c_mktsegment, 28 | c_comment, 29 | getdate() as hoy, 30 | GETDATE AS get_date_caps_test, 31 | sysdate() AS sys_date_col_test, 32 | SYSDATE() AS sys_date_caps_col_test, 33 | ISNULL(test, test_is_null) AS null_test_col_caps, 34 | ISNULL(test, test_is_null) AS null_test_col_caps, 35 | isnull(test, 'test_is_null') AS null_test_col, 36 | date_part(year, date(origination_date)) || '-' || 'Q' || floor( 37 | (date_part(month, date(origination_date)) - 1) / 3) + 1 as origination_quarter, 38 | date_part(SECONDS, '2019-10-01 00:00:01.000001'::timestamp) 39 | first_value( 40 | case when colA = 2 then id2 41 | end ignore nulls 42 | ) over ( 43 | partition by 44 | customer_id 45 | order by 46 | created_at 47 | rows between unbounded preceding and unbounded following 48 | ) as test_syntax_change 49 | from 50 | redshift_sample_data.tpch_rs1.customer 51 | ORDER BY colC,colB DESC -------------------------------------------------------------------------------- /models/redshift/r2/customerrs.sql: -------------------------------------------------------------------------------- 1 | 2 | {{ 3 | config( 4 | materialized = 'table' 5 | ) 6 | }} 7 | 8 | select 9 | convert(string,c_custkey) as stringkey, 10 | c_name, 11 | c_address, 12 | c_nationkey, 13 | c_phone, 14 | (to_char(date_trunc('month', getdate()), 'YYYY-MM')) as month, 15 | datediff(days, getdate(), getdate()) as days_since_oldest_unpaid_due_date, 16 | date_trunc('months', getdate()), 17 | dateadd('day', -1, getdate()), 18 | case when 'organictest' ~ 'organic|email' then 'match' else 'no match' end as regexmatch, 19 | case when 'organictest' !~ 'organic|email' then 'antimatch' else 'antino match' end as antiregexmatch 20 | dlog10(c_acctbal) as actbalbaseten, 21 | dlog10(c_acctbal) as actbalbaseten, 22 | JSON_EXTRACT_PATH_TEXT('{"f2":{"f3":1},"f4":{"f5":99,"f6":"star"}}','f4', 'f6'), 23 | dexp(100), 24 | date_part(dow, 2008-01-05 14:00:00), 25 | hll_cardinality(expr), 26 | JSON_ARRAY_LENGTH('[11,12,13,{"f1":21,"f2":[25,26]},14]'), 27 | c_mktsegment, 28 | c_comment, 29 | getdate() as hoy, 30 | GETDATE AS get_date_caps_test, 31 | sysdate() AS sys_date_col_test, 32 | SYSDATE() AS sys_date_caps_col_test, 33 | ISNULL(test, test_is_null) AS null_test_col_caps, 34 | ISNULL(test, test_is_null) AS null_test_col_caps, 35 | isnull(test, 'test_is_null') AS null_test_col, 36 | date_part(year, date(origination_date)) || '-' || 'Q' || floor( 37 | (date_part(month, date(origination_date)) - 1) / 3) + 1 as origination_quarter, 38 | date_part(SECONDS, '2019-10-01 00:00:01.000001'::timestamp) 39 | first_value( 40 | case when colA = 2 then id2 41 | end ignore nulls 42 | ) over ( 43 | partition by 44 | customer_id 45 | order by 46 | created_at 47 | rows between unbounded preceding and unbounded following 48 | ) as test_syntax_change 49 | from 50 | redshift_sample_data.tpch_rs1.customer 51 | ORDER BY colC,colB DESC -------------------------------------------------------------------------------- /models/snowflake/customer.sql: -------------------------------------------------------------------------------- 1 | 2 | {{ 3 | config( 4 | materialized = 'table' 5 | ) 6 | }} 7 | 8 | 9 | select 10 | zeroifnull(c_custkey) as intkey, 11 | contains(c_name,'customer') as namecontains, 12 | c_address, 13 | c_nationkey, 14 | c_phone, 15 | to_number(c_acctbal, 10, 5) as cleanacctbal, 16 | c_mktsegment, 17 | c_comment, 18 | last_query_id() as lastquery, 19 | current_transaction() as ct, 20 | convert_timezone(test), 21 | to_varchar(test), 22 | parse_json(testuno), 23 | parse_json(testdos), 24 | Name, 25 | Age, 26 | CAST(ID AS VARCHAR) as id_text, 27 | created_date::TIME, 28 | CAST(file_dump AS NUMBER) as file_dump_numeric, 29 | COALESCE(col1::FLOAT,col2::FLOAT8,col3::REAL) AS xyz 30 | FROM catalog.schema.table1 31 | WHERE colA = colB::TEXT 32 | AND somethingelse = 1 33 | 34 | from 35 | snowflake_sample_data.tpch_sf1.customer 36 | 37 | -------------------------------------------------------------------------------- /models/snowflake/lineitem.sql: -------------------------------------------------------------------------------- 1 | 2 | {{ 3 | config( 4 | materialized = 'table' 5 | ) 6 | }} 7 | 8 | 9 | select 10 | l_orderkey, 11 | l_partkey, 12 | l_suppkey, 13 | l_linenumber, 14 | l_quantity, 15 | l_extendedprice, 16 | l_discount, 17 | l_tax, 18 | l_returnflag, 19 | l_linestatus, 20 | timestampadd('year', 2, l_shipdate) as shipadd, 21 | timestampdiff('day',l_receiptdate, l_shipdate) as receiptdiff, 22 | dayname(l_commitdate) as daycommit, 23 | l_shipinstruct, 24 | l_shipmode, 25 | l_comment, 26 | current_version() as cv, 27 | get_ddl('table', 'snowflake_sample_data.tpch_sf1.lineitem') as ddl, 28 | timestampdiff(getdate(), getdate(), getdate()) 29 | 30 | 31 | from 32 | snowflake_sample_data.tpch_sf1.lineitem 33 | 34 | -------------------------------------------------------------------------------- /profiles.yml: -------------------------------------------------------------------------------- 1 | lakehouse: 2 | target: snow 3 | 4 | outputs: 5 | 6 | snow: 7 | type: snowflake 8 | account: "{{ env_var('SNOWFLAKE_TEST_ACCOUNT') }}" 9 | user: "{{ env_var('SNOWFLAKE_TEST_USER') }}" 10 | password: "{{ env_var('SNOWFLAKE_TEST_PASSWORD') }}" 11 | role: "{{ env_var('SNOWFLAKE_TEST_ROLE') }}" 12 | database: "{{ env_var('SNOWFLAKE_TEST_DATABASE') }}" 13 | warehouse: "{{ env_var('SNOWFLAKE_TEST_WAREHOUSE') }}" 14 | schema: "{{ env_var('SNOWFLAKE_TEST_SCHEMA') }}" 15 | 16 | 17 | databricks: 18 | type: databricks 19 | method: http 20 | catalog: "{{ env_var('DATABRICKS_TEST_CATALOG') }}" 21 | schema: "{{ env_var('DATABRICKS_TEST_SCHEMA') }}" 22 | host: "{{ env_var('DATABRICKS_TEST_HOST') }}" 23 | token: "{{ env_var('DATABRICKS_TEST_TOKEN') }}" 24 | http_path: "{{ env_var('DATABRICKS_TEST_PATH') }}" 25 | 26 | 27 | 28 | 29 | -------------------------------------------------------------------------------- /seeds/redshift/functionlistrs.csv: -------------------------------------------------------------------------------- 1 | function_name 2 | convert 3 | TEXT_TO_NUMERIC_ALT 4 | HLL_COMBINE_SKETCHES 5 | hll_combine 6 | hll_create_sketch 7 | hll_cardinality 8 | dexp 9 | dlog10 10 | dlog1 11 | getdate 12 | strtol 13 | isnull 14 | sysdate 15 | datediff 16 | date_trunc 17 | date_part -------------------------------------------------------------------------------- /seeds/snowflake/blockedfunctionlist.csv: -------------------------------------------------------------------------------- 1 | function_name,udf 2 | convert_timezone,"CREATE OR REPLACE FUNCTION convert_timezone(source STRING, target STRING, stamp TIMESTAMP) 3 | RETURNS TIMESTAMP 4 | RETURN from_utc_timestamp(to_utc_timestamp(stamp, source), target);" 5 | to_varchar,"CREATE OR REPLACE FUNCTION to_varchar(arg DOUBLE) 6 | RETURNS STRING 7 | RETURN CAST(arg AS STRING);" 8 | parse_json,"(string) from_json(string, schema_of_json(string)) -- not supproted, we dont support variants-- would string be sufficient if they just want to query semi-structured data?" 9 | to_char,"CREATE OR REPLACE FUNCTION to_char(arg DOUBLE) 10 | RETURNS STRING 11 | RETURN CAST(arg AS STRING);" 12 | last_query_id,no databricks equivalent 13 | array_construct, 14 | object_construct,how do we make this kwargs? RS TODO 15 | is_null_value,(string) isnull(string) 16 | current_transaction,no databricks equivalent 17 | object_insert,no databricks equivalent 18 | check_json,no databricks equivalent 19 | hll_export,no databricks equivalent 20 | decrypt,no databricks equivalent 21 | get,not supported 22 | current_region,no equivalent 23 | get_ddl,further research needed 24 | try_parse_json,no equivalent 25 | to_geography,no equivalent 26 | parse_xml,no equivalent 27 | object_delete,no equivalent 28 | standardize,unable to find? 29 | hll_estimate,no equivalent 30 | get_path, 31 | st_intersects, 32 | to_numeric,"(arg, expr, p, s) to_number(arg, expr, p, s)" 33 | try_to_date,no comparable databricks dql 34 | try_to_timestamp,no comparable databricks dql 35 | as_varchar,dbx does not recognize variant input 36 | as_char,dbx does not recognize variant input 37 | to_timestamp_ltz,when using to_timestamp databricks will apply the offset rather than persisting it. 38 | current_version,no databricks equivalent dql 39 | minhash_combine,no databricks equivalent dql 40 | truncate,no databricks equivalent dql 41 | try_to_boolean,no databricks equivalent dql 42 | try_to_timestamp_ntz,no databricks equivalent dql 43 | current_role,no databricks equivalent dql 44 | hll,HLL can take in any expression whereas cardinality only takes in array/map expressions 45 | approximate_similarity,no databricks equivalent dql 46 | objectagg,dbx does not support objects or variants 47 | ratio_to_report,no databricks equivalent dql 48 | is_role_in_session,no databricks equivalent dql 49 | time_slice,no databricks equivalent dql 50 | is_integer,no databricks equivalent dql 51 | unicode,no databricks equivalent dql 52 | to_variant,dbx does not support variant 53 | xmlget,no databricks equivalent dql 54 | try_to_time,no databricks equivalent dql 55 | is_real,no databricks equivalent dql 56 | minhash,no databricks equivalent dql 57 | current_warehouse,no databricks equivalent dql 58 | to_double,no databricks equivalent dql 59 | to_object,dbx does not support object 60 | md5_number_lower64,no databricks equivalent dql 61 | encrypt,"aes_encrypt use binary key, not varchar passphrase. encrypt_raw can probably be transpiled" 62 | object_keys,json_object_keys 63 | current_client,no databricks equivalent dql 64 | try_to_timestamp_tz,dbx does not support timestamp_tz 65 | compress,no databricks equivalent dql 66 | md5_number_upper64,no databricks equivalent dql 67 | is_date,no databricks equivalent dql 68 | array_construct_compact,no way to pass in kwargs to macro. we could ask to pass in a list but that would require a bit of manual intervention. 69 | as_integer,dbx does not support variant input 70 | enrich_placement_ad_type,no databricks equivalent dql 71 | approximate_jaccard_index,no databricks equivalent dql 72 | as_date,dbx does not support variant input 73 | md5_hex,no databricks equivalent dql 74 | randstr,no databricks equivalent dql 75 | hash_agg,no databricks equivalent dql 76 | hll_import,no databricks equivalent dql 77 | is_boolean,dbx does not take in variant args 78 | as_number,dbx does not take in variant args 79 | hex_decode_binary,no databricks equivalent dql 80 | last_transaction,no databricks equivalent dql 81 | sha2_binary,no databricks equivalent dql 82 | try_base64_decode_string,no databricks equivalent dql -------------------------------------------------------------------------------- /seeds/snowflake/functionlist.csv: -------------------------------------------------------------------------------- 1 | function_name 2 | md5_binary 3 | json_extract_path 4 | base64_encode 5 | zeroifnull 6 | seq4 7 | strtok_to_array 8 | to_number 9 | array_size 10 | dateadd 11 | dayname 12 | timestampadd 13 | week 14 | timediff 15 | date_from_parts 16 | monthname 17 | timestampdiff 18 | to_time 19 | timeadd 20 | try_to_number 21 | try_to_numeric 22 | to_decimal 23 | to_numeric 24 | try_to_decimal 25 | to_boolean 26 | to_array 27 | listagg 28 | array_to_string 29 | hll_estimate 30 | uniform 31 | div0 32 | square 33 | uuid_string 34 | time 35 | previous_day 36 | array_intersection 37 | sysdate 38 | sha2_hex 39 | dayofweekiso 40 | nullifzero 41 | array_cat 42 | seq8 43 | timestamp_from_parts 44 | weekiso 45 | boolor_agg 46 | yearofweekiso 47 | insert 48 | array_slice 49 | bitand 50 | timestamp_ntz_from_parts 51 | base64_decode_string 52 | systimestamp 53 | hex_decode_string 54 | variance_samp 55 | seq2 56 | base64_decode_binary 57 | booland_agg 58 | seq1 59 | yearofweek 60 | sha1_hex 61 | strtok 62 | -------------------------------------------------------------------------------- /seeds/snowflake/springbrickstests.csv: -------------------------------------------------------------------------------- 1 | function_name,input,expected_output 2 | any_value,, 3 | approx_top_k,, 4 | approximate_count_distinct,, 5 | approximate_jaccard_index,, 6 | approximate_similarity,, 7 | array_agg,coffee,"coffee, iced tea, latte, tea" 8 | array_agg,iced tea,"coffee, iced tea, latte, tea" 9 | array_agg,latte,"coffee, iced tea, latte, tea" 10 | array_agg,tea,"coffee, iced tea, latte, tea" 11 | array_append,, 12 | array_cat,"coffee, iced tea","coffee, iced tea, latte, tea" 13 | array_cat,"latte,tea","coffee, iced tea, latte, tea" 14 | array_compact,, 15 | array_construct,, 16 | array_construct_compact,, 17 | array_insert,, 18 | array_intersection,, 19 | array_size,, 20 | array_slice,, 21 | array_to_string,, 22 | arrayagg,, 23 | as_char,, 24 | as_date,, 25 | as_integer,, 26 | as_number,, 27 | as_varchar,, 28 | base64_decode_binary,, 29 | base64_decode_string,, 30 | base64_encode,, 31 | bitand,, 32 | booland_agg,, 33 | boolor_agg,, 34 | boolxor_agg,, 35 | charindex,, 36 | check_json,, 37 | compress,, 38 | contains,coffee,FALSE 39 | contains,iced tea,TRUE 40 | contains,latte,TRUE 41 | contains,tea,TRUE 42 | contains,NULL,NULL 43 | control.harmonize_compact,, 44 | convert_timezone,, 45 | date_from_parts,"{""col1"":""2023"",""col2"":""01"",""col3"":""10""}",10/1/2023 46 | dateadd,"{""col1"":""day"",""col2"":""7"",""col3"":""2023-01-10""}",17/1/2023 47 | dateadd,"{""col1"":""minute"",""col2"":""11"",""col3"":""2023-01-10 7:13""}",10/1/2023 7:24 48 | dayname,3/5/2023,Wed 49 | dayname,8/5/2023 11:15,Mon 50 | dayofweekiso,3/5/2023,3 51 | dayofweekiso,8/5/2023 11:15,1 52 | decrypt,, 53 | div0,, 54 | editdistance,, 55 | encrypt,, 56 | endswith,, 57 | enrich_placement_ad_type,, 58 | equal_null,, 59 | get,, 60 | get_ddl,, 61 | get_path,, 62 | getdate,, 63 | hash_agg,, 64 | hex_decode_binary,, 65 | hex_decode_string,, 66 | hll,, 67 | hll_estimate,, 68 | hll_export,, 69 | hll_import,, 70 | iff,, 71 | ilike,, 72 | insert,, 73 | is_boolean,, 74 | is_date,, 75 | is_integer,, 76 | is_null_value,, 77 | is_real,, 78 | is_role_in_session,, 79 | json_extract_path_text,, 80 | last_query_id,, 81 | last_transaction,, 82 | len,, 83 | listagg,, 84 | md5_binary,Snowflake,EDF1439075A83A447FB8B630DDC9C8DE 85 | md5_hex,, 86 | md5_number_lower64,, 87 | md5_number_upper64,, 88 | median,, 89 | minhash,, 90 | minhash_combine,, 91 | mode,, 92 | monthname,1/5/2015,May 93 | monthname,3/4/2015 10:00,Apr 94 | nullifzero,, 95 | object_agg,, 96 | object_construct,, 97 | object_delete,, 98 | object_insert,, 99 | object_keys,, 100 | objectagg,, 101 | parse_json,, 102 | parse_xml,, 103 | percentile_cont,, 104 | percentile_disc,, 105 | previous_day,, 106 | randstr,, 107 | ratio_to_report,, 108 | regexp,, 109 | regexp_count,, 110 | regexp_instr,, 111 | regexp_like,, 112 | regexp_substr,, 113 | seq1,, 114 | seq2,, 115 | seq4,, 116 | seq8,, 117 | sha1_hex,, 118 | sha2_binary,, 119 | sha2_hex,, 120 | split_part,"{11.22.33, ""."", 0}",11 121 | split_part,"{11.22.33, ""."", 1}",11 122 | split_part,"{11.22.33, ""."", 2}",22 123 | split_part,"{11.22.33, ""."", 3}",33 124 | split_part,"{11.22.33, ""."", 4}", 125 | split_part,"{11.22.33, ""."", -1}",33 126 | split_part,"{11.22.33, ""."", -2}",22 127 | split_part,"{11.22.33, ""."", -3}",11 128 | split_part,"{11.22.33, ""."", -4}", 129 | square,, 130 | st_intersects,, 131 | standardize,, 132 | startswith,coffee,FALSE 133 | startswith,iced tea,FALSE 134 | startswith,latte,FALSE 135 | startswith,tea,TRUE 136 | startswith,NULL,NULL 137 | strtok,, 138 | strtok_to_array,"{""col1:""a.b.c"",""col2"", "".""}","[""a"", ""b"", ""c""]" 139 | strtok_to_array,"{""col1"":""user@snowflake.com"", ""col2"":"".@""}","[""user"",""snowflake"",""com""]" 140 | sysdate,, 141 | systimestamp,, 142 | time,, 143 | time_slice,, 144 | timeadd,"{""col1"":""year"", ""col2"":2, ""col3"":""2013-05-08""}","""2015-05-08""" 145 | timeadd,"{""col1"":""hour"", ""col2"":2, ""col3"": ""2013-04-05 02:00:00.000""}","""2015-05-08""" 146 | timediff,"{""col1"":""year"", ""col2"":""2017-01-01"",""col3"":""2019-01-01""}",2 147 | timediff,"{""col1"":""month"", ""col2"":""2017-01-01"", ""col3"":""2017-12-31""}",11 148 | timestamp_from_parts,, 149 | timestamp_ntz_from_parts,, 150 | timestampadd,"{""col1"":year"", ""col2"": 2, ""col3"":""2013-05-08""}","""2015-05-08""" 151 | timestampadd,"{""col1"":""hour"", ""col2"":2, ""col3"":""2013-04-05 00:00:00.000""}","""2013-04-05 02:00:00""" 152 | timestampdiff,"{""col1"":""year"",""col2"": ""2017-01-01"",""col3"": ""2019-01-01""}",2 153 | timestampdiff,"{""col1"":""month"", ""col2"":""2017-01-01"",""col3"": ""2017-12-31""}",11 154 | to_array,1,[1] 155 | to_array,3,[3] 156 | to_binary,"(""col1"": ""SNOW"", ""col2"":utf-8"")",534E4F57 157 | to_boolean,yes,TRUE 158 | to_boolean,no,FALSE 159 | to_boolean,NULL,NULL 160 | to_boolean,1,TRUE 161 | to_boolean,0,FALSE 162 | to_boolean,NULL,NULL 163 | to_char,"{""col1"":'2013-04-05 01:02:03', ""col2"":'mm/dd/yyyy', ""col3"":'hh23:mi hours'}","{""col1"":'04/05/2013', ""col2"":'01:02 hours'}" 164 | to_char,"{""col1"":""03-May-2013""}",3/5/2013 165 | to_char,"{""col1"":""03-May-2013"", ""col2"":""yyyy.mm.dd""}",2013.05.03 166 | to_number,12.3456,12 167 | to_number,98.76546,99 168 | to_number,"{12.3456, 10, 1}",12.3 169 | to_number,"{98.76546, 10, 1}",98.8 170 | to_number,"{12.3456, 10, 8}",12.3456 171 | to_number,"{98.76546, 10, 8}",98.7645 172 | to_double,, 173 | to_geography,, 174 | to_decimal,1, 175 | to_decimal,-12.3, 176 | to_decimal,0, 177 | to_decimal,-0.1, 178 | to_decimal,"{1, '99.9', 9, 5}",1.00000' 179 | to_decimal,"{-12.3, '99.9', 9, 5}",-12.30000' 180 | to_decimal,"{0.0, '99.9', 9, 5}",0.00000' 181 | to_decimal,"{-0.1, '99.9', 9, 5}",-0.10000' 182 | to_decimal,"{1, 'TM9', 9, 5}",1.00000' 183 | to_decimal,"{1, 'TM9', 9, 5}",-12.30000' 184 | to_decimal,"{1, 'TM9', 9, 5}",0.00000' 185 | to_decimal,"{1, 'TM9', 9, 5}",-0.10000' 186 | to_numeric,12.3456,12 187 | to_numeric,98.76546,99 188 | to_numeric,"{12.3456, 10, 1}",12.3 189 | to_numeric,"{98.76546, 10, 1}",98.8 190 | to_numeric,"{12.3456, 10, 8}",12.3456 191 | to_numeric,"{98.76546, 10, 8}",98.7645 192 | to_object,, 193 | to_time,"{""col"":'13:30:00'}",13:30:00' 194 | to_time,"{""col1"":'11.15.00', '""col2"":'HH24.MI.SS'}",11:15:00' 195 | to_timestamp_ltz,, 196 | to_timestamp_ntz,todo, 197 | to_timestamp_tz,todo, 198 | to_varchar,"{""col1"":'2013-04-05 01:02:03', ""col2"":'mm/dd/yyyy, hh24:mi hours'}","{'04/05/2013', '01:02 hours'}" 199 | to_varchar,"{""03-May-2013""}",3/5/2013 200 | to_varchar,"{""col1"":""03-May-2013"", ""col2"":""yyyy.mm.dd""}",2013.05.03 201 | to_variant,, 202 | truncate,, 203 | try_base64_decode_string,, 204 | try_cast,"{""col1"":'05-Mar-2016',""col2"": 'AS TIMESTAMP'}",2016-03-05 00:00:00:000 205 | try_cast,"{""col1"":'05/2016', ""col2"":'AS TIMESTAMP'}",NULL 206 | try_cast,"{""col1"":'ABCD', ""col2"":'AS CHAR(2)'}",NULL 207 | try_cast,"{""col1"":'ABCD',""col2"": 'AS VARCHAR(10)'}",ABCD 208 | try_parse_json,, 209 | try_to_binary,, 210 | try_to_boolean,, 211 | try_to_date,, 212 | try_to_decimal,345.123,345 213 | try_to_decimal,"{345.123, 10, 2}",345.12 214 | try_to_decimal,"{345.123, 4, 2}",NULL 215 | try_to_decimal,"{'$345.12', '$999.00'}",345 216 | try_to_decimal,"{'$345.12', '$999.00', 5, 2}",345.12 217 | try_to_decimal,"{'$345.12', 5, 2}",NULL 218 | try_to_number,345.123,345 219 | try_to_number,"{345.123, 10, 2}",345.12 220 | try_to_number,"{345.123, 4, 2}",NULL 221 | try_to_number,"{'$345.12', '$999.00'}",345 222 | try_to_number,"{'$345.12', '$999.00', 5, 2}",345.12 223 | try_to_number,"{'$345.12', 5, 2}",NULL 224 | try_to_numeric,345.123,345 225 | try_to_numeric,"{345.123, 10, 2}",345.12 226 | try_to_numeric,"{345.123, 4, 2}",NULL 227 | try_to_numeric,"{'$345.12', '$999.00'}",345 228 | try_to_numeric,"{'$345.12', '$999.00', 5, 2}",345.12 229 | try_to_numeric,"{'$345.12', 5, 2}",NULL 230 | try_to_time,, 231 | try_to_timestamp,, 232 | try_to_timestamp_ntz,, 233 | try_to_timestamp_tz,, 234 | unicode,, 235 | uniform,, 236 | uuid_string,, 237 | variance_samp,, 238 | week,2016-01-02 23:39:20.123',53 239 | weekiso,, 240 | xmlget,, 241 | yearofweek,, 242 | yearofweekiso,, 243 | zeroifnull,1,1 244 | zeroifnull,NULL,0 245 | zeroifnull,5,5 246 | zeroifnull,0,0 247 | zeroifnull,3.14159,3.14159 -------------------------------------------------------------------------------- /seeds/snowflake/wipfunctionlist.csv: -------------------------------------------------------------------------------- 1 | function_name,udf 2 | editdistance,"CREATE OR REPLACE FUNCTION editdistance(s1 STRING, s2 STRING) 3 | RETURNS INT 4 | RETURN levenshtein(s1, s2); 5 | 6 | CREATE OR REPLACE FUNCTION editdistance(s1 STRING, s2 STRING, max_length INT) 7 | RETURNS INT 8 | RETURN levenshtein(substr(s1,1,max_length), substr(s2,1,max_length));" 9 | uniform,"CREATE OR REPLACE FUNCTION uniform(min DOUBLE, max DOUBLE, rand DOUBLE) 10 | RETURNS DOUBLE 11 | RETURN min + (max - min) * rand;" 12 | div0,"CREATE OR REPLACE FUNCTION div0(arg1 DOUBLE, arg2 DOUBLE) 13 | RETURNS DOUBLE 14 | RETURN CASE WHEN arg2 = 0 THEN 0 ELSE arg1 / arg2 END;" 15 | square,"CREATE OR REPLACE FUNCTION square(arg DOUBLE) 16 | RETURNS DOUBLE 17 | RETURN arg * arg;" 18 | uuid_string,"CREATE OR REPLACE FUNCTION uuid_string() 19 | RETURNS STRING 20 | RETURNS uuid();" 21 | time," to_timestamp(expr, 'HH:mm:ss')" 22 | previous_day,"CREATE OR REPLACE FUNCTION previous_day(arg DATE, day STRING) 23 | RETURNS DATE 24 | RETURN CASE WHEN substr(dayname(arg), 1, 2) = substr(day, 1, 2) THEN arg - INTERVAL 7 DAY 25 | ELSE next_day(arg, day) - INTERVAL 7 DAY END;" 26 | " to_number(arg, scale, precision) -- take scale, precision convert to format","(arg, scale, precision) to_number(num_expr, [scale|fmt]) -- if logic to gen expression" 27 | array_intersection,"CREATE OR REPLACE FUNCTION array_intersection (arg1 ARRAY, arg2 ARRAY) 28 | RETURNS ARRAY 29 | RETURN array_intersect(arg1, arg2);" 30 | sysdate,"CREATE OR REPLACE FUNCTION sysdate() 31 | RETURNS TIMESTAMP 32 | RETURN to_utc_timestamp(current_timestamp(), current_timezone());" 33 | sha2_hex,"CREATE OR REPLACE FUNCTION sha2_hex(arg BINARY, len INT) 34 | RETURNS STRING 35 | RETURN sha2(arg, len);" 36 | dayofweekiso,"CREATE OR REPLACE FUNCTION dayofweekiso(arg TIMESTAMP) 37 | RETURNS INT 38 | RETURN EXTRACT(DAYOFWEEK_ISO FROM arg);" 39 | nullifzero,"CREATE OR REPLACE FUNCTION nullifzero(arg DOUBLE) 40 | RETURNS DOUBLE 41 | RETURN nullif(arg, 0);" 42 | array_cat,"CREATE OR REPLACE FUNCTION array_cat(arg1 ARRAY, arg2 ARRAY) 43 | RETURNS ARRAY 44 | RETURN concat(arg1, arg2);" 45 | seq8,"CREATE OR REPLACE FUNCTION seq8() 46 | RETURNS BIGINT 47 | RETURN monotonically_increasing_id();" 48 | timestamp_from_parts,"CREATE OR REPLACE FUNCTION timestamp_from_parts(year INT, month INT, day INT, hour INT, minute INT, second DECIMAL(10, 6)) 49 | RETURNS TIMESTAMP 50 | RETURN make_timestamp(year, month, day, hour, minute, second);" 51 | weekiso,"CREATE OR REPLACE FUNCTION weekiso(arg TIMESTAMP) 52 | RETURNS TIMESTAMP 53 | RETURN EXTRACT(WEEK FROM arg);" 54 | boolor_agg,bool_or 55 | yearofweekiso,"CREATE OR REPLACE FUNCTION yearofweekiso(arg TIMESTAMP) 56 | RETURNS INT 57 | RETURN EXTRACT(YEAROFWEEK FROM arg);" 58 | insert,"CREATE OR REPLACE FUNCTION insert(base STRING, pos INT, len INT, ins STRING) 59 | RETURNS STRING 60 | RETURN overlay(base, ins, pos, len);" 61 | array_slice,slice() 62 | current_time,parse subset of current_timestamp 63 | bitand,"CREATE OR REPLACE FUNCTION bitand(arg1 BIGINT, arg2 BIGINT) 64 | RETURNS INT 65 | RETURN arg1 & arg2;" 66 | timestamp_ntz_from_parts,check logic for date_from_parts 67 | base64_decode_string,"CREATE OR REPLACE FUNCTION base64_decode_string(arg STRING) 68 | RETURNS STRING 69 | RETURN unbase64(arg);" 70 | systimestamp,"CREATE OR REPLACE FUNCTION systimestamp() 71 | RETURNS TIMESTAMP 72 | RETURN current_timestamp();" 73 | hex_decode_string,"CREATE OR REPLACE FUNCTION hex_decode_string(arg1 STRING) 74 | RETURNS STRING 75 | RETURN decode(unhex(arg1), 'UTF-8');" 76 | variance_samp,var_samp 77 | seq2,"CREATE OR REPLACE FUNCTION seq2() 78 | RETURNS SMALLINT 79 | RETURN monotonically_increasing_id();" 80 | base64_decode_binary,"CREATE OR REPLACE FUNCTION base64_decode_binary(arg STRING) 81 | RETURNS BINARY 82 | RETURN unbase64(arg);" 83 | seq1,"CREATE OR REPLACE FUNCTION seq1() 84 | RETURNS BYTE 85 | RETURN monotonically_increasing_id();" 86 | yearofweek,"CREATE OR REPLACE FUNCTION yearofweek(arg TIMESTAMP) 87 | RETURNS TIMESTAMP 88 | RETURN EXTRACT(YEAROFWEEK FROM arg);" 89 | sha1_hex,"CREATE OR REPLACE FUNCTION sha1_hex(arg BINARY, len INT) 90 | RETURNS STRING 91 | RETURN sha1(arg, len);" 92 | strtok,"CREATE OR REPLACE FUNCTION strtok(arg STRING, delim STRING, part INT) 93 | RETURNS STRING 94 | RETURN element_at(split(arg, delim), part); " -------------------------------------------------------------------------------- /tests/Redshift/assert_convert.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | '5.6' as inputuno, 5 | '5' as snowoutputuno, 6 | {{convert('INT', 'inputuno')}} as dbxoutputuno, 7 | '5.6' as inputdos, 8 | '6' as snowoutputdos, 9 | {{convert('DECIMAL(2, 0)', 'inputdos')}} as dbxoutputdos, 10 | '-5.6' as inputtres, 11 | '-5' as snowoutputtres, 12 | {{convert('INT', 'inputtres')}} as dbxoutputtres 13 | 14 | 15 | ) 16 | 17 | select * 18 | from test 19 | where (snowoutputuno <> dbxoutputuno 20 | or snowoutputdos <> dbxoutputdos 21 | or snowoutputtres <> dbxoutputtres) -------------------------------------------------------------------------------- /tests/Redshift/assert_strtol.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | 'abcd1234' as inputuno, 5 | '2882343476' as snowoutputuno, 6 | {{strtol('inputuno', 16)}} as dbxoutputuno, 7 | '1234567' as inputdos, 8 | '342391' as snowoutputdos, 9 | {{strtol('inputdos', 8)}} as dbxoutputdos, 10 | '110101' as inputtres, 11 | '53' as snowoutputtres, 12 | {{strtol('inputtres', 2)}} as dbxoutputtres 13 | 14 | 15 | ) 16 | 17 | select * 18 | from test 19 | where (snowoutputuno <> dbxoutputuno 20 | or snowoutputdos <> dbxoutputdos 21 | or snowoutputtres <> dbxoutputtres) -------------------------------------------------------------------------------- /tests/Redshift/dlog1.sql: -------------------------------------------------------------------------------- 1 | with 2 | 3 | test as ( 4 | 5 | select 6 | 7 | 8 | 1 as redshiftoutput, 9 | 10 | {{dlog1(2.718281828)}} as dbxouput 11 | 12 | ) 13 | 14 | select * 15 | from test 16 | where redshiftoutput <> dbxoutput -------------------------------------------------------------------------------- /tests/Redshift/dlog10.sql: -------------------------------------------------------------------------------- 1 | with 2 | 3 | test as ( 4 | 5 | select 6 | 7 | 8 | 2 as redshiftoutput, 9 | 10 | {{dlog10(100)}} as dbxouput 11 | 12 | ) 13 | 14 | select * 15 | from test 16 | where redshiftoutput <> dbxoutput -------------------------------------------------------------------------------- /tests/Redshift/hll.sql: -------------------------------------------------------------------------------- 1 | with parse as ( 2 | SELECT inputuno FROM VALUES (1), (2), (3), (4) AS (inputuno) 3 | ), 4 | 5 | 6 | test as ( 7 | 8 | select 9 | 10 | 11 | 4 as redshiftoutput, 12 | 13 | {{hll('inputuno')}} as dbxoutput 14 | from parse 15 | 16 | 17 | ) 18 | 19 | select * 20 | from test 21 | where redshiftoutput <> dbxoutput -------------------------------------------------------------------------------- /tests/Redshift/test_dexp.sql: -------------------------------------------------------------------------------- 1 | -- tests/test_dexp.sql 2 | 3 | SELECT 4 | value, 5 | {{ dexp('value') }} as exponential_value 6 | FROM 7 | dbt.dbt_schema.test 8 | -------------------------------------------------------------------------------- /tests/Redshift/test_texttonumericalt.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | '1.5' as inputuno, 5 | '2' as snowoutputuno, 6 | {{texttonumericalt('inputuno')}} as dbxoutputuno, 7 | '2.51' as inputdos, 8 | '3' as snowoutputdos, 9 | {{texttonumericalt('inputdos')}} as dbxoutputdos, 10 | '123.52501' as inputtres, 11 | '123.53' as snowoutputtres, 12 | {{texttonumericalt('inputtres', 10, 2)}} as dbxoutputtres 13 | 14 | 15 | ) 16 | 17 | select * 18 | from test 19 | where (snowoutputuno <> dbxoutputuno 20 | or snowoutputdos <> dbxoutputdos 21 | or snowoutputtres <> dbxoutputtres) 22 | -------------------------------------------------------------------------------- /tests/Snowflake/README.md: -------------------------------------------------------------------------------- 1 | The purpose of this directory is to trigger end to end unit tests that showcase how given a specific input, the Databricks macro invocation output matches the Snowflake output. To validate this first execute dbt seed and then run dbt test. In the main branch of this source code the test success rate should always be 100%. TODO: add unit test for hll_estimate and array_to_join 2 | -------------------------------------------------------------------------------- /tests/Snowflake/assert_base64_encode.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | 'Snowflake' as inputuno, 5 | 'U25vd2ZsYWtl' as snowoutputuno, 6 | {{base64_encode('inputuno')}} as dbxoutputuno 7 | 8 | 9 | 10 | 11 | ) 12 | 13 | select * 14 | from test 15 | where (snowoutputuno <> dbxoutputuno) 16 | -------------------------------------------------------------------------------- /tests/Snowflake/assert_contains.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | {{contains('input','"te"')}} as actual_output 7 | from {{ ref('springbrickstests')}} 8 | where function_name = 'contains' 9 | ) 10 | 11 | select * 12 | from test 13 | where expected_output::boolean <> actual_output 14 | -------------------------------------------------------------------------------- /tests/Snowflake/assert_date_from_parts.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | input:col1 as year, 7 | input:col2 as month, 8 | input:col3 as day, 9 | to_date(expected_output,'d/M/yyyy[ H:m]') as expected_output_formatted 10 | 11 | from {{ ref('springbrickstests')}} 12 | where function_name = 'date_from_parts' 13 | ), 14 | 15 | test as ( 16 | select input, 17 | expected_output_formatted, 18 | {{date_from_parts('year','month','day')}} as actual_output 19 | from testraw 20 | 21 | ) 22 | 23 | select * 24 | from test 25 | where expected_output_formatted <> actual_output 26 | -------------------------------------------------------------------------------- /tests/Snowflake/assert_dayname.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | to_date(input,'d/M/yyyy[ H:m]') as input_formatted 7 | 8 | from {{ ref('springbrickstests')}} 9 | where function_name = 'dayname' 10 | ), 11 | 12 | test as ( 13 | select input, 14 | expected_output, 15 | {{dayname('input_formatted')}} as actual_output 16 | from testraw 17 | 18 | ) 19 | 20 | select * 21 | from test 22 | where expected_output <> actual_output 23 | -------------------------------------------------------------------------------- /tests/Snowflake/assert_dayofweekiso.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | to_date(input,'d/M/yyyy[ H:m]') as input_formatted 7 | 8 | from {{ ref('springbrickstests')}} 9 | where function_name = 'dayofweekiso' 10 | ), 11 | 12 | test as ( 13 | select input, 14 | expected_output, 15 | {{dayofweekiso('input_formatted')}} as actual_output 16 | from testraw 17 | 18 | ) 19 | 20 | select * 21 | from test 22 | where expected_output <> actual_output 23 | -------------------------------------------------------------------------------- /tests/Snowflake/assert_json_extract_path_text.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output 6 | 7 | from {{ ref('springbrickstests')}} 8 | where function_name = 'json_extract_path_text' 9 | ), 10 | 11 | test as ( 12 | select input, 13 | expected_output, 14 | {{json_extract_path_text('input','col1')}} as actual_output 15 | from testraw 16 | 17 | ) 18 | 19 | select * 20 | from test 21 | where expected_output <> actual_output 22 | -------------------------------------------------------------------------------- /tests/Snowflake/assert_listagg.sql: -------------------------------------------------------------------------------- 1 | with parse as ( 2 | SELECT inputuno FROM VALUES (41445), (55937), (67781), (80550) AS (inputuno) 3 | ), 4 | 5 | 6 | test as ( 7 | 8 | select 9 | 10 | 11 | "41445 55937 67781 80550" as snowoutputuno, 12 | 13 | {{listagg('inputuno',' ')}} as dbxoutputuno 14 | from parse 15 | group by 1 16 | 17 | ) 18 | 19 | select * 20 | from test 21 | where snowoutputuno <> dbxoutputuno 22 | -------------------------------------------------------------------------------- /tests/Snowflake/assert_listaggdistinct.sql: -------------------------------------------------------------------------------- 1 | with parse as ( 2 | 3 | SELECT inputdos FROM VALUES ('F'), ('O'), ('F'), ('O') AS (inputdos) 4 | 5 | ), 6 | 7 | 8 | test as ( 9 | 10 | select 11 | 12 | 13 | "F|O" as snowoutputdos, 14 | 15 | {{listagg('distinct inputdos','|')}} as dbxoutputdos 16 | from parse 17 | group by 1 18 | 19 | ) 20 | 21 | select * 22 | from test 23 | where snowoutputdos <> dbxoutputdos 24 | -------------------------------------------------------------------------------- /tests/Snowflake/assert_md5_binary.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | {{md5_binary('input')}} as actual_output 7 | from {{ ref('springbrickstests')}} 8 | where function_name = 'md5_binary' 9 | ) 10 | 11 | select * 12 | from test 13 | where expected_output <> upper(actual_output) 14 | -------------------------------------------------------------------------------- /tests/Snowflake/assert_monthname.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | to_date(input,'d/M/yyyy[ H:m]') as input_formatted 7 | 8 | from {{ ref('springbrickstests')}} 9 | where function_name = 'monthname' 10 | ), 11 | 12 | test as ( 13 | select input, 14 | expected_output, 15 | {{monthname('input_formatted')}} as actual_output 16 | from testraw 17 | 18 | ) 19 | 20 | select * 21 | from test 22 | where expected_output <> actual_output 23 | -------------------------------------------------------------------------------- /tests/Snowflake/assert_startswith.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | {{startswith('input','"te"')}} as actual_output 7 | from {{ ref('springbrickstests')}} 8 | where function_name = 'startswith' 9 | 10 | ) 11 | 12 | select * 13 | from test 14 | where expected_output::boolean <> actual_output 15 | -------------------------------------------------------------------------------- /tests/Snowflake/assert_strtok_to_array.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | input:col1 as expr, 7 | input:col2 as delim 8 | 9 | from {{ ref('springbrickstests')}} 10 | where function_name = 'strtok_to_array' 11 | ), 12 | 13 | test as ( 14 | select input, 15 | expected_output, 16 | {{strtok_to_array('expr', 'delim')}} as actual_output 17 | from testraw 18 | 19 | ) 20 | 21 | select * 22 | from test 23 | where expected_output = actual_output::string 24 | -------------------------------------------------------------------------------- /tests/Snowflake/assert_to_array.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | {{to_array('input')}} as actual_output 7 | from {{ ref('springbrickstests')}} 8 | where function_name = 'to_array' 9 | ) 10 | 11 | select * 12 | from test 13 | where expected_output <> actual_output::string 14 | -------------------------------------------------------------------------------- /tests/Snowflake/assert_to_boolean.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | {{to_boolean('input')}} as actual_output 7 | from {{ ref('springbrickstests')}} 8 | where function_name = 'to_boolean' 9 | ) 10 | 11 | select * 12 | from test 13 | where lower(expected_output) <> actual_output::string 14 | -------------------------------------------------------------------------------- /tests/Snowflake/assert_to_time.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | input:col1 as expr 7 | 8 | from {{ ref('springbrickstests')}} 9 | where function_name = 'to_time' 10 | ), 11 | 12 | test as ( 13 | select input, 14 | expected_output, 15 | {{to_time('expr')}} as actual_output 16 | from testraw 17 | 18 | ) 19 | 20 | select * 21 | from test 22 | where expected_output <> actual_output 23 | -------------------------------------------------------------------------------- /tests/Snowflake/assert_week.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | {{week('input')}} as actual_output 7 | from {{ ref('springbrickstests')}} 8 | where function_name = 'week' 9 | ) 10 | 11 | select * 12 | from test 13 | where expected_output <> actual_output::string 14 | -------------------------------------------------------------------------------- /tests/Snowflake/assert_zeroifnull.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | input, 5 | input::decimal(9,5) as inputdec, 6 | expected_output, 7 | {{zeroifnull('inputdec')}} as actual_output 8 | from {{ ref('springbrickstests')}} 9 | where function_name = 'zeroifnull' 10 | ) 11 | 12 | select * 13 | from test 14 | where expected_output <> actual_output 15 | -------------------------------------------------------------------------------- /tests/Snowflake/asset_to_decimal.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | '12.3456' as inputuno, 5 | '12' as snowoutputuno, 6 | {{to_decimal('inputuno')}} as dbxoutputuno, 7 | '12.3' as snowoutputunoa, 8 | '12.3456' as snowoutputunob, 9 | {{to_decimal('inputuno', 10, 1)}} as dbxoutputunoa , 10 | {{to_decimal('inputuno', 10, 8)}} as dbxoutputunob , 11 | '98.76546' as inputdos, 12 | '99' as snowoutputdos, 13 | '98.8' as snowoutputdosa, 14 | '98.76546' as snowoutputdosb, 15 | {{to_decimal('inputdos')}} as dbxoutputdos, 16 | {{to_decimal('inputdos', 10, 1)}} as dbxoutputdosa, 17 | {{to_decimal('inputdos', 10, 8)}} as dbxoutputdosb, 18 | '12.3' as inputtres, 19 | '12.3' as snowoutputtres, 20 | '12.3' as snowoutputtresa, 21 | '12.3' as snowoutputtresb, 22 | {{to_decimal('inputtres', '99.9')}} as dbxoutputtres, 23 | {{to_decimal('inputtres', '99.9', 9, 5)}} as dbxoutputtresa, 24 | {{to_decimal('inputtres', 'TM9', 9, 5)}} as dbxoutputtresb 25 | 26 | 27 | 28 | ) 29 | 30 | select * 31 | from test 32 | where (snowoutputuno <> dbxoutputuno or snowoutputunoa <> dbxoutputunoa or snowoutputunob <> dbxoutputunob 33 | or snowoutputdos <> dbxoutputdos or snowoutputdosa <> dbxoutputdosa or snowoutputdosb <> dbxoutputdosb 34 | or snowoutputtres <> dbxoutputtres or snowoutputtresa <> dbxoutputtresa or snowoutputtresb <> dbxoutputtresb) -------------------------------------------------------------------------------- /tests/Snowflake/asset_to_number.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | '12.3456' as inputuno, 5 | '12' as snowoutputuno, 6 | {{to_number('inputuno')}} as dbxoutputuno, 7 | '12.3' as snowoutputunoa, 8 | '12.3456' as snowoutputunob, 9 | {{to_number('inputuno', 10, 1)}} as dbxoutputunoa , 10 | {{to_number('inputuno', 10, 8)}} as dbxoutputunob , 11 | '98.76546' as inputdos, 12 | '99' as snowoutputdos, 13 | '98.8' as snowoutputdosa, 14 | '98.76546' as snowoutputdosb, 15 | {{to_number('inputdos')}} as dbxoutputdos, 16 | {{to_number('inputdos', 10, 1)}} as dbxoutputdosa, 17 | {{to_number('inputdos', 10, 8)}} as dbxoutputdosb, 18 | '12.3' as inputtres, 19 | '12.3' as snowoutputtres, 20 | '12.3' as snowoutputtresa, 21 | '12.3' as snowoutputtresb, 22 | {{to_number('inputtres', '99.9')}} as dbxoutputtres, 23 | {{to_number('inputtres', '99.9', 9, 5)}} as dbxoutputtresa, 24 | {{to_number('inputtres', 'TM9', 9, 5)}} as dbxoutputtresb 25 | 26 | 27 | 28 | ) 29 | 30 | select * 31 | from test 32 | where (snowoutputuno <> dbxoutputuno or snowoutputunoa <> dbxoutputunoa or snowoutputunob <> dbxoutputunob 33 | or snowoutputdos <> dbxoutputdos or snowoutputdosa <> dbxoutputdosa or snowoutputdosb <> dbxoutputdosb 34 | or snowoutputtres <> dbxoutputtres or snowoutputtresa <> dbxoutputtresa or snowoutputtresb <> dbxoutputtresb) -------------------------------------------------------------------------------- /tests/Snowflake/asset_to_numeric.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | '12.3456' as inputuno, 5 | '12' as snowoutputuno, 6 | {{to_numeric('inputuno')}} as dbxoutputuno, 7 | '12.3' as snowoutputunoa, 8 | '12.3456' as snowoutputunob, 9 | {{to_numeric('inputuno', 10, 1)}} as dbxoutputunoa , 10 | {{to_numeric('inputuno', 10, 8)}} as dbxoutputunob , 11 | '98.76546' as inputdos, 12 | '99' as snowoutputdos, 13 | '98.8' as snowoutputdosa, 14 | '98.76546' as snowoutputdosb, 15 | {{to_numeric('inputdos')}} as dbxoutputdos, 16 | {{to_numeric('inputdos', 10, 1)}} as dbxoutputdosa, 17 | {{to_numeric('inputdos', 10, 8)}} as dbxoutputdosb, 18 | '12.3' as inputtres, 19 | '12.3' as snowoutputtres, 20 | '12.3' as snowoutputtresa, 21 | '12.3' as snowoutputtresb, 22 | {{to_numeric('inputtres', '99.9')}} as dbxoutputtres, 23 | {{to_numeric('inputtres', '99.9', 9, 5)}} as dbxoutputtresa, 24 | {{to_numeric('inputtres', 'TM9', 9, 5)}} as dbxoutputtresb 25 | 26 | 27 | 28 | ) 29 | 30 | select * 31 | from test 32 | where (snowoutputuno <> dbxoutputuno or snowoutputunoa <> dbxoutputunoa or snowoutputunob <> dbxoutputunob 33 | or snowoutputdos <> dbxoutputdos or snowoutputdosa <> dbxoutputdosa or snowoutputdosb <> dbxoutputdosb 34 | or snowoutputtres <> dbxoutputtres or snowoutputtresa <> dbxoutputtresa or snowoutputtresb <> dbxoutputtresb) -------------------------------------------------------------------------------- /tests/Snowflake/asset_try_to_decimal.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | '345.123' as inputuno, 5 | '345' as snowoutputuno, 6 | {{try_to_decimal('inputuno')}} as dbxoutputuno, 7 | '345.12' as snowoutputunoa, 8 | 'NULL' as snowoutputunob, 9 | {{try_to_decimal('inputuno', 10, 2)}} as dbxoutputunoa , 10 | {{try_to_decimal('inputuno', 4, 2)}} as dbxoutputunob , 11 | '$345.12' as inputdos, 12 | '345.12' as snowoutputdos, 13 | 'NULL' as snowoutputdosb, 14 | {{try_to_decimal('inputdos', "$999.00")}} as dbxoutputdos, 15 | {{try_to_decimal('inputdos', 5, 2)}} as dbxoutputdosb 16 | 17 | 18 | 19 | ) 20 | 21 | select * 22 | from test 23 | where (snowoutputuno <> dbxoutputuno or snowoutputunoa <> dbxoutputunoa 24 | or snowoutputdos <> dbxoutputdos) 25 | -------------------------------------------------------------------------------- /tests/Snowflake/asset_try_to_number.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | '345.123' as inputuno, 5 | '345' as snowoutputuno, 6 | {{try_to_number('inputuno')}} as dbxoutputuno, 7 | '345.12' as snowoutputunoa, 8 | 'NULL' as snowoutputunob, 9 | {{try_to_number('inputuno', 10, 2)}} as dbxoutputunoa , 10 | {{try_to_number('inputuno', 4, 2)}} as dbxoutputunob , 11 | '$345.12' as inputdos, 12 | '345.12' as snowoutputdos, 13 | 'NULL' as snowoutputdosb, 14 | {{try_to_number('inputdos', "$999.00")}} as dbxoutputdos, 15 | {{try_to_number('inputdos', 5, 2)}} as dbxoutputdosb 16 | 17 | 18 | 19 | ) 20 | 21 | select * 22 | from test 23 | where (snowoutputuno <> dbxoutputuno or snowoutputunoa <> dbxoutputunoa 24 | or snowoutputdos <> dbxoutputdos) 25 | -------------------------------------------------------------------------------- /tests/Snowflake/asset_try_to_numeric.sql: -------------------------------------------------------------------------------- 1 | with test as ( 2 | 3 | select 4 | '345.123' as inputuno, 5 | '345' as snowoutputuno, 6 | {{try_to_numeric('inputuno')}} as dbxoutputuno, 7 | '345.12' as snowoutputunoa, 8 | 'NULL' as snowoutputunob, 9 | {{try_to_numeric('inputuno', 10, 2)}} as dbxoutputunoa , 10 | {{try_to_numeric('inputuno', 4, 2)}} as dbxoutputunob , 11 | '$345.12' as inputdos, 12 | '345.12' as snowoutputdos, 13 | 'NULL' as snowoutputdosb, 14 | {{try_to_numeric('inputdos', "$999.00")}} as dbxoutputdos, 15 | {{try_to_numeric('inputdos', 5, 2)}} as dbxoutputdosb 16 | 17 | 18 | 19 | ) 20 | 21 | select * 22 | from test 23 | where (snowoutputuno <> dbxoutputuno or snowoutputunoa <> dbxoutputunoa 24 | or snowoutputdos <> dbxoutputdos) 25 | -------------------------------------------------------------------------------- /tests/Snowflake/timediff.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | input:col1 as unit, 7 | input:col2 as timeuno, 8 | input:col3 as timedos 9 | 10 | from {{ ref('springbrickstests')}} 11 | where function_name = 'timediff' 12 | ), 13 | 14 | test as ( 15 | select input, 16 | expected_output, 17 | {{timediff('unit', 'timeuno', 'timedos')}} as actual_output 18 | from testraw 19 | 20 | ) 21 | 22 | select * 23 | from test 24 | where expected_output <> actual_output 25 | -------------------------------------------------------------------------------- /tests/Snowflake/timestampadd.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | input:col1 as unit, 7 | input:col2 as measure, 8 | input:col3 as base 9 | 10 | from {{ ref('springbrickstests')}} 11 | where function_name = 'timestampadd' 12 | ), 13 | 14 | test as ( 15 | select input, 16 | expected_output, 17 | {{timestampadd('unit', 'measure', 'base')}} as actual_output, 18 | concat('"',actual_output, '"') as actual_output_quotes 19 | from testraw 20 | 21 | ) 22 | 23 | select * 24 | from test 25 | where expected_output <> actual_output_quotes 26 | -------------------------------------------------------------------------------- /tests/Snowflake/timestampdiff.sql: -------------------------------------------------------------------------------- 1 | with testraw as ( 2 | 3 | select 4 | input, 5 | expected_output, 6 | input:col1 as unit, 7 | input:col2 as timeuno, 8 | input:col3 as timedos 9 | 10 | from {{ ref('springbrickstests')}} 11 | where function_name = 'timestampdiff' 12 | ), 13 | 14 | test as ( 15 | select input, 16 | expected_output, 17 | {{timestampdiff('unit', 'timeuno', 'timedos')}} as actual_output 18 | from testraw 19 | 20 | ) 21 | 22 | select * 23 | from test 24 | where expected_output <> actual_output 25 | -------------------------------------------------------------------------------- /tmp/beyondsqltest/testlookmlfiles/dos.lkml: -------------------------------------------------------------------------------- 1 | dos = """{{ 2 | config( 3 | materialized = 'table' 4 | ) 5 | }} 6 | 7 | select 8 | convert(string,c_custkey) as stringkey, 9 | c_name, 10 | c_address, 11 | c_nationkey, 12 | c_phone, 13 | dlog10(c_acctbal) as actbalbaseten, 14 | dlog10(c_acctbal) as actbalbaseten, 15 | JSON_EXTRACT_PATH_TEXT('{"f2":{"f3":1},"f4":{"f5":99,"f6":"star"}}','f4', 'f6'), 16 | dexp(100), 17 | date_part(dow, 2008-01-05 14:00:00), 18 | hll_cardinality(expr), 19 | JSON_ARRAY_LENGTH('[11,12,13,{"f1":21,"f2":[25,26]},14]'), 20 | c_mktsegment, 21 | c_comment, 22 | getdate() as hoy, 23 | GETDATE AS get_date_caps_test, 24 | sysdate() AS sys_date_col_test, 25 | SYSDATE() AS sys_date_caps_col_test, 26 | ISNULL(test, test_is_null) AS null_test_col_caps, 27 | ISNULL(test, test_is_null) AS null_test_col_caps, 28 | isnull(test, 'test_is_null') AS null_test_col, 29 | date_part(year, date(origination_date)) || '-' || 'Q' || floor( 30 | (date_part(month, date(origination_date)) - 1) / 3) + 1 as origination_quarter, 31 | date_part(SECONDS, '2019-10-01 00:00:01.000001'::timestamp) 32 | first_value( 33 | case when colA = 2 then id2 34 | end ignore nulls 35 | ) over ( 36 | partition by 37 | customer_id 38 | order by 39 | created_at 40 | rows between unbounded preceding and unbounded following 41 | ) as test_syntax_change 42 | from 43 | redshift_sample_data.tpch_rs1.customer 44 | ORDER BY colC,colB DESC)""" -------------------------------------------------------------------------------- /tmp/beyondsqltest/testlookmlfiles/tres.lkml: -------------------------------------------------------------------------------- 1 | uno = """{{ 2 | config( 3 | materialized = 'table' 4 | ) 5 | }} 6 | 7 | select 8 | convert(string,c_custkey) as stringkey, 9 | c_name, 10 | c_address, 11 | c_nationkey, 12 | c_phone, 13 | dlog10(c_acctbal) as actbalbaseten, 14 | dlog10(c_acctbal) as actbalbaseten, 15 | JSON_EXTRACT_PATH_TEXT('{"f2":{"f3":1},"f4":{"f5":99,"f6":"star"}}','f4', 'f6'), 16 | dexp(100), 17 | date_part(dow, 2008-01-05 14:00:00), 18 | hll_cardinality(expr), 19 | JSON_ARRAY_LENGTH('[11,12,13,{"f1":21,"f2":[25,26]},14]'), 20 | c_mktsegment, 21 | c_comment, 22 | getdate() as hoy, 23 | GETDATE AS get_date_caps_test, 24 | sysdate() AS sys_date_col_test, 25 | SYSDATE() AS sys_date_caps_col_test, 26 | ISNULL(test, test_is_null) AS null_test_col_caps, 27 | ISNULL(test, test_is_null) AS null_test_col_caps, 28 | isnull(test, 'test_is_null') AS null_test_col, 29 | date_part(year, date(origination_date)) || '-' || 'Q' || floor( 30 | (date_part(month, date(origination_date)) - 1) / 3) + 1 as origination_quarter, 31 | date_part(SECONDS, '2019-10-01 00:00:01.000001'::timestamp) 32 | first_value( 33 | case when colA = 2 then id2 34 | end ignore nulls 35 | ) over ( 36 | partition by 37 | customer_id 38 | order by 39 | created_at 40 | rows between unbounded preceding and unbounded following 41 | ) as test_syntax_change 42 | from 43 | redshift_sample_data.tpch_rs1.customer 44 | ORDER BY colC,colB DESC)""" -------------------------------------------------------------------------------- /tmp/beyondsqltest/testlookmlfiles/uno.lkml: -------------------------------------------------------------------------------- 1 | uno = """{{ 2 | config( 3 | materialized = 'table' 4 | ) 5 | }} 6 | 7 | select 8 | convert(string,c_custkey) as stringkey, 9 | c_name, 10 | c_address, 11 | c_nationkey, 12 | c_phone, 13 | dlog10(c_acctbal) as actbalbaseten, 14 | dlog10(c_acctbal) as actbalbaseten, 15 | JSON_EXTRACT_PATH_TEXT('{"f2":{"f3":1},"f4":{"f5":99,"f6":"star"}}','f4', 'f6'), 16 | dexp(100), 17 | date_part(dow, 2008-01-05 14:00:00), 18 | hll_cardinality(expr), 19 | JSON_ARRAY_LENGTH('[11,12,13,{"f1":21,"f2":[25,26]},14]'), 20 | c_mktsegment, 21 | c_comment, 22 | getdate() as hoy, 23 | GETDATE AS get_date_caps_test, 24 | sysdate() AS sys_date_col_test, 25 | SYSDATE() AS sys_date_caps_col_test, 26 | ISNULL(test, test_is_null) AS null_test_col_caps, 27 | ISNULL(test, test_is_null) AS null_test_col_caps, 28 | isnull(test, 'test_is_null') AS null_test_col, 29 | date_part(year, date(origination_date)) || '-' || 'Q' || floor( 30 | (date_part(month, date(origination_date)) - 1) / 3) + 1 as origination_quarter, 31 | date_part(SECONDS, '2019-10-01 00:00:01.000001'::timestamp) 32 | first_value( 33 | case when colA = 2 then id2 34 | end ignore nulls 35 | ) over ( 36 | partition by 37 | customer_id 38 | order by 39 | created_at 40 | rows between unbounded preceding and unbounded following 41 | ) as test_syntax_change 42 | from 43 | redshift_sample_data.tpch_rs1.customer 44 | ORDER BY colC,colB DESC)""" 45 | print(uno) -------------------------------------------------------------------------------- /tmp/beyondsqltest/testpyfiles/dos.py: -------------------------------------------------------------------------------- 1 | dos = """{{ 2 | config( 3 | materialized = 'table' 4 | ) 5 | }} 6 | 7 | select 8 | convert(string,c_custkey) as stringkey, 9 | c_name, 10 | c_address, 11 | c_nationkey, 12 | c_phone, 13 | dlog10(c_acctbal) as actbalbaseten, 14 | dlog10(c_acctbal) as actbalbaseten, 15 | JSON_EXTRACT_PATH_TEXT('{"f2":{"f3":1},"f4":{"f5":99,"f6":"star"}}','f4', 'f6'), 16 | dexp(100), 17 | date_part(dow, 2008-01-05 14:00:00), 18 | hll_cardinality(expr), 19 | JSON_ARRAY_LENGTH('[11,12,13,{"f1":21,"f2":[25,26]},14]'), 20 | c_mktsegment, 21 | c_comment, 22 | getdate() as hoy, 23 | GETDATE AS get_date_caps_test, 24 | sysdate() AS sys_date_col_test, 25 | SYSDATE() AS sys_date_caps_col_test, 26 | ISNULL(test, test_is_null) AS null_test_col_caps, 27 | ISNULL(test, test_is_null) AS null_test_col_caps, 28 | isnull(test, 'test_is_null') AS null_test_col, 29 | date_part(year, date(origination_date)) || '-' || 'Q' || floor( 30 | (date_part(month, date(origination_date)) - 1) / 3) + 1 as origination_quarter, 31 | date_part(SECONDS, '2019-10-01 00:00:01.000001'::timestamp) 32 | first_value( 33 | case when colA = 2 then id2 34 | end ignore nulls 35 | ) over ( 36 | partition by 37 | customer_id 38 | order by 39 | created_at 40 | rows between unbounded preceding and unbounded following 41 | ) as test_syntax_change 42 | from 43 | redshift_sample_data.tpch_rs1.customer 44 | ORDER BY colC,colB DESC)""" 45 | print(dos) -------------------------------------------------------------------------------- /tmp/beyondsqltest/testpyfiles/tres.py: -------------------------------------------------------------------------------- 1 | tres = """{{ 2 | config( 3 | materialized = 'table' 4 | ) 5 | }} 6 | 7 | select 8 | convert(string,c_custkey) as stringkey, 9 | c_name, 10 | c_address, 11 | c_nationkey, 12 | c_phone, 13 | dlog10(c_acctbal) as actbalbaseten, 14 | dlog10(c_acctbal) as actbalbaseten, 15 | JSON_EXTRACT_PATH_TEXT('{"f2":{"f3":1},"f4":{"f5":99,"f6":"star"}}','f4', 'f6'), 16 | dexp(100), 17 | date_part(dow, 2008-01-05 14:00:00), 18 | hll_cardinality(expr), 19 | JSON_ARRAY_LENGTH('[11,12,13,{"f1":21,"f2":[25,26]},14]'), 20 | c_mktsegment, 21 | c_comment, 22 | getdate() as hoy, 23 | GETDATE AS get_date_caps_test, 24 | sysdate() AS sys_date_col_test, 25 | SYSDATE() AS sys_date_caps_col_test, 26 | ISNULL(test, test_is_null) AS null_test_col_caps, 27 | ISNULL(test, test_is_null) AS null_test_col_caps, 28 | isnull(test, 'test_is_null') AS null_test_col, 29 | date_part(year, date(origination_date)) || '-' || 'Q' || floor( 30 | (date_part(month, date(origination_date)) - 1) / 3) + 1 as origination_quarter, 31 | date_part(SECONDS, '2019-10-01 00:00:01.000001'::timestamp) 32 | first_value( 33 | case when colA = 2 then id2 34 | end ignore nulls 35 | ) over ( 36 | partition by 37 | customer_id 38 | order by 39 | created_at 40 | rows between unbounded preceding and unbounded following 41 | ) as test_syntax_change 42 | from 43 | redshift_sample_data.tpch_rs1.customer 44 | ORDER BY colC,colB DESC)""" 45 | print(tres) -------------------------------------------------------------------------------- /tmp/beyondsqltest/testpyfiles/uno.py: -------------------------------------------------------------------------------- 1 | uno = """{{ 2 | config( 3 | materialized = 'table' 4 | ) 5 | }} 6 | 7 | select 8 | convert(string,c_custkey) as stringkey, 9 | c_name, 10 | c_address, 11 | c_nationkey, 12 | c_phone, 13 | dlog10(c_acctbal) as actbalbaseten, 14 | dlog10(c_acctbal) as actbalbaseten, 15 | JSON_EXTRACT_PATH_TEXT('{"f2":{"f3":1},"f4":{"f5":99,"f6":"star"}}','f4', 'f6'), 16 | dexp(100), 17 | date_part(dow, 2008-01-05 14:00:00), 18 | hll_cardinality(expr), 19 | JSON_ARRAY_LENGTH('[11,12,13,{"f1":21,"f2":[25,26]},14]'), 20 | c_mktsegment, 21 | c_comment, 22 | getdate() as hoy, 23 | GETDATE AS get_date_caps_test, 24 | sysdate() AS sys_date_col_test, 25 | SYSDATE() AS sys_date_caps_col_test, 26 | ISNULL(test, test_is_null) AS null_test_col_caps, 27 | ISNULL(test, test_is_null) AS null_test_col_caps, 28 | isnull(test, 'test_is_null') AS null_test_col, 29 | date_part(year, date(origination_date)) || '-' || 'Q' || floor( 30 | (date_part(month, date(origination_date)) - 1) / 3) + 1 as origination_quarter, 31 | date_part(SECONDS, '2019-10-01 00:00:01.000001'::timestamp) 32 | first_value( 33 | case when colA = 2 then id2 34 | end ignore nulls 35 | ) over ( 36 | partition by 37 | customer_id 38 | order by 39 | created_at 40 | rows between unbounded preceding and unbounded following 41 | ) as test_syntax_change 42 | from 43 | redshift_sample_data.tpch_rs1.customer 44 | ORDER BY colC,colB DESC)""" 45 | print(uno) -------------------------------------------------------------------------------- /tmp/redshift/customerrs.sql: -------------------------------------------------------------------------------- 1 | 2 | {{ 3 | config( 4 | materialized = 'table' 5 | ) 6 | }} 7 | 8 | 9 | select 10 | {{ convert('string', 'c_custkey') }} as stringkey, 11 | c_name, 12 | c_address, 13 | c_nationkey, 14 | c_phone, 15 | {{ dlog10('c_acctbal') }} as actbalbaseten, 16 | c_mktsegment, 17 | c_comment, 18 | {{ getdate() }} as hoy 19 | 20 | 21 | 22 | 23 | from 24 | samples.tpch.customer 25 | 26 | -------------------------------------------------------------------------------- /tmp/snow/customerdb.sql: -------------------------------------------------------------------------------- 1 | 2 | {{ 3 | config( 4 | materialized = 'table' 5 | ) 6 | }} 7 | 8 | 9 | select 10 | {{ zeroifnull('c_custkey') }} as intkey, 11 | {{ contains('c_name','"customer"') }} as namecontains, 12 | c_address, 13 | c_nationkey, 14 | c_phone, 15 | {{ to_number ('c_acctbal', 10, 5)}} as cleanacctbal, 16 | c_mktsegment, 17 | c_comment 18 | 19 | 20 | 21 | 22 | from 23 | samples.tpch.customer 24 | 25 | -------------------------------------------------------------------------------- /tmp/snow/lineitemdb.sql: -------------------------------------------------------------------------------- 1 | 2 | {{ 3 | config( 4 | materialized = 'table', 5 | tag = 'dbx' 6 | ) 7 | }} 8 | 9 | 10 | select 11 | l_orderkey, 12 | l_partkey, 13 | l_suppkey, 14 | l_linenumber, 15 | l_quantity, 16 | l_extendedprice, 17 | l_discount, 18 | l_tax, 19 | l_returnflag, 20 | l_linestatus, 21 | {{ timestampadd('"year"', 2, 'l_shipdate') }} as shipadd, 22 | {{ timestampdiff('"day"','l_receiptdate', 'l_shipdate') }} as receiptdiff, 23 | {{ dayname ('l_commitdate')}} as daycommit, 24 | l_shipinstruct, 25 | l_shipmode, 26 | l_comment 27 | 28 | 29 | from 30 | samples.tpch.lineitem 31 | --------------------------------------------------------------------------------