From b512b1687764cf2a5e4c9c6aec8f6e868c19eb8a Mon Sep 17 00:00:00 2001 From: Matt Shaver <60105315+matthewshaver@users.noreply.github.com> Date: Tue, 14 May 2024 14:04:19 -0400 Subject: [PATCH 1/7] Redshift unit test limitation --- .../resource-configs/redshift-configs.md | 85 +++++++++++++++++++ 1 file changed, 85 insertions(+) diff --git a/website/docs/reference/resource-configs/redshift-configs.md b/website/docs/reference/resource-configs/redshift-configs.md index 83e6efb05ca..2dd7827d6b0 100644 --- a/website/docs/reference/resource-configs/redshift-configs.md +++ b/website/docs/reference/resource-configs/redshift-configs.md @@ -257,3 +257,88 @@ The workaround is to execute `DROP MATERIALIZED VIEW my_mv CASCADE` on the data + + + +## Unit test limitations + +Unit tests aren't supported on Redshift if the SQL in the common table expression (CTE) contains functions such as `LISTAGG`, `MEDIAN`, `PERCENTILE_CONT`, etc. Those functions must be executed against a user-created table. dbt combines given rows to be part of the CTE, which is unsupported by Redshift. You can try the following SQL: + +```sql + +create temporary table "test_tmpxxxxx" as ( + with test_fixture as ( + select + cast(1000 as integer) as id, + cast('menu1' as character varying(500)) as name, + cast( 1 as integer) as quantity + union all + select + cast(1001 as integer) as id, + cast('menu2' as character varying(500)) as name, + cast( 1 as integer) as quantity + union all + select + cast(1003 as integer) as id, + cast('menu1' as character varying(500)) as name, + cast( 1 as integer) as quantity + ), + agg as ( + SELECT + LISTAGG(name || ' x ' || quantity, ',') AS option_name_list, + id + FROM test_fixture + GROUP BY id + ) + select * from agg +); + +``` +This results in the error: + +```bash + +[XX000] ERROR: One or more of the used functions must be applied on at least one user created tables. Examples of user table only functions are LISTAGG, MEDIAN, PERCENTILE_CONT, etc + +``` + +However, the following query works as expected: + +```sql + +create temporary table "test_tmp1234" as ( + SELECT + cast(1000 as integer) as id, + cast('menu1' as character varying(500)) as name, + cast( 1 as integer) as quantity + union all + select + cast(1001 as integer) as id, + cast('menu2' as character varying(500)) as name, + cast( 1 as integer) as quantity + union all + select + cast(1000 as integer) as id, + cast('menu1' as character varying(500)) as name, + cast( 1 as integer) as quantity +); + +with agg as ( + SELECT + LISTAGG(name || ' x ' || quantity, ',') AS option_name_list, + id + FROM test_tmp1234 + GROUP BY id +) +select * from agg; + +``` + +If all given rows are created as a temporary table first, then running the test by referring to it will result in a successful run. + +In short, separate the unit tests into two steps: +1. Prepare test fixtures by creating temporary tables. +2. Run unit test query by referring to the temporary tables. + + + From afdd265bd7314ea551b3eb3de9a8c56935d5a3b7 Mon Sep 17 00:00:00 2001 From: Matt Shaver <60105315+matthewshaver@users.noreply.github.com> Date: Tue, 14 May 2024 14:13:52 -0400 Subject: [PATCH 2/7] Adding to unit test page --- website/docs/docs/build/unit-tests.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/website/docs/docs/build/unit-tests.md b/website/docs/docs/build/unit-tests.md index 033e55ab504..78aba3213bf 100644 --- a/website/docs/docs/build/unit-tests.md +++ b/website/docs/docs/build/unit-tests.md @@ -26,8 +26,8 @@ With dbt Core v1.8 and dbt Cloud environments that opt to "Keep on latest versio - You must specify all fields in a BigQuery STRUCT in a unit test. You cannot use only a subset of fields in a STRUCT. - If your model has multiple versions, by default the unit test will run on *all* versions of your model. Read [unit testing versioned models](#unit-testing-versioned-models) for more information. - Unit tests must be defined in a YML file in your `models/` directory. -- Available to dbt Cloud customers who have selected ["Keep on latest version"](/docs/dbt-versions/upgrade-dbt-version-in-cloud#keep-on-latest-version) and dbt Core v1.8.0 or later. - Table names must be [aliased](/docs/build/custom-aliases) in order to unit test `join` logic. +- Redshift customers need to be aware of a [limitation when building unit tests](/reference/resource-configs/redshift-configs#unit-test-limitations) that requires a workaround. Read the [reference doc](/reference/resource-properties/unit-tests) for more details about formatting your unit tests. From 1402048b7f8f412050645013593e69efbc18f84c Mon Sep 17 00:00:00 2001 From: Matt Shaver <60105315+matthewshaver@users.noreply.github.com> Date: Tue, 14 May 2024 18:28:13 -0400 Subject: [PATCH 3/7] Update website/docs/reference/resource-configs/redshift-configs.md Co-authored-by: Leona B. Campbell <3880403+runleonarun@users.noreply.github.com> --- website/docs/reference/resource-configs/redshift-configs.md | 4 +++- 1 file changed, 3 insertions(+), 1 deletion(-) diff --git a/website/docs/reference/resource-configs/redshift-configs.md b/website/docs/reference/resource-configs/redshift-configs.md index 2dd7827d6b0..f0115ef10b8 100644 --- a/website/docs/reference/resource-configs/redshift-configs.md +++ b/website/docs/reference/resource-configs/redshift-configs.md @@ -262,7 +262,9 @@ The workaround is to execute `DROP MATERIALIZED VIEW my_mv CASCADE` on the data ## Unit test limitations -Unit tests aren't supported on Redshift if the SQL in the common table expression (CTE) contains functions such as `LISTAGG`, `MEDIAN`, `PERCENTILE_CONT`, etc. Those functions must be executed against a user-created table. dbt combines given rows to be part of the CTE, which is unsupported by Redshift. You can try the following SQL: +Redshift doesn't support Unit tests when the SQL in the common table expression (CTE) contains functions such as `LISTAGG`, `MEDIAN`, `PERCENTILE_CONT`, etc. These functions must be executed against a user-created table. dbt combines given rows to be part of the CTE, which Redshift does not support. + +The following query illustrates this limitation: ```sql From d2d127ff337112580c7cffd8e41b92e3e308ab83 Mon Sep 17 00:00:00 2001 From: Matt Shaver <60105315+matthewshaver@users.noreply.github.com> Date: Tue, 14 May 2024 18:29:54 -0400 Subject: [PATCH 4/7] Update website/docs/reference/resource-configs/redshift-configs.md Co-authored-by: Leona B. Campbell <3880403+runleonarun@users.noreply.github.com> --- website/docs/reference/resource-configs/redshift-configs.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/website/docs/reference/resource-configs/redshift-configs.md b/website/docs/reference/resource-configs/redshift-configs.md index f0115ef10b8..5df67460f1d 100644 --- a/website/docs/reference/resource-configs/redshift-configs.md +++ b/website/docs/reference/resource-configs/redshift-configs.md @@ -336,7 +336,7 @@ select * from agg; ``` -If all given rows are created as a temporary table first, then running the test by referring to it will result in a successful run. +When all given rows are created as a temporary table first, then running the test by referring to the temporary tables results in a successful run. In short, separate the unit tests into two steps: 1. Prepare test fixtures by creating temporary tables. From 8c7860a283d0a379a0fc85a02f626ff49c63626d Mon Sep 17 00:00:00 2001 From: Matt Shaver <60105315+matthewshaver@users.noreply.github.com> Date: Wed, 15 May 2024 13:14:12 -0400 Subject: [PATCH 5/7] Update website/docs/reference/resource-configs/redshift-configs.md --- website/docs/reference/resource-configs/redshift-configs.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/website/docs/reference/resource-configs/redshift-configs.md b/website/docs/reference/resource-configs/redshift-configs.md index 5df67460f1d..f45993a40bc 100644 --- a/website/docs/reference/resource-configs/redshift-configs.md +++ b/website/docs/reference/resource-configs/redshift-configs.md @@ -296,7 +296,7 @@ create temporary table "test_tmpxxxxx" as ( ); ``` -This results in the error: +This query results in the error: ```bash From 4577afd9df5b6a619de71e4e0075147d26b566f8 Mon Sep 17 00:00:00 2001 From: Matt Shaver <60105315+matthewshaver@users.noreply.github.com> Date: Wed, 15 May 2024 13:20:33 -0400 Subject: [PATCH 6/7] Update website/docs/reference/resource-configs/redshift-configs.md --- website/docs/reference/resource-configs/redshift-configs.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/website/docs/reference/resource-configs/redshift-configs.md b/website/docs/reference/resource-configs/redshift-configs.md index f45993a40bc..7695cb21ec7 100644 --- a/website/docs/reference/resource-configs/redshift-configs.md +++ b/website/docs/reference/resource-configs/redshift-configs.md @@ -262,7 +262,7 @@ The workaround is to execute `DROP MATERIALIZED VIEW my_mv CASCADE` on the data ## Unit test limitations -Redshift doesn't support Unit tests when the SQL in the common table expression (CTE) contains functions such as `LISTAGG`, `MEDIAN`, `PERCENTILE_CONT`, etc. These functions must be executed against a user-created table. dbt combines given rows to be part of the CTE, which Redshift does not support. +Redshift doesn't support Unit tests when the SQL in the common table expression (CTE) contains functions such as `LISTAGG`, `MEDIAN`, `PERCENTILE_CONT`, etc. These functions must be executed against a user-created table. dbt combines given rows to be part of the CTE, which Redshift does not support. For unit tests to function properly in this scenario, creating temporary tables for the unit tests to reference is a good workaround. The following query illustrates this limitation: From 96137fdf352d65b6a6ed99078f75d1e5b09de2b5 Mon Sep 17 00:00:00 2001 From: Matt Shaver <60105315+matthewshaver@users.noreply.github.com> Date: Wed, 15 May 2024 13:20:51 -0400 Subject: [PATCH 7/7] Update website/docs/reference/resource-configs/redshift-configs.md --- website/docs/reference/resource-configs/redshift-configs.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/website/docs/reference/resource-configs/redshift-configs.md b/website/docs/reference/resource-configs/redshift-configs.md index 7695cb21ec7..7c66be66f92 100644 --- a/website/docs/reference/resource-configs/redshift-configs.md +++ b/website/docs/reference/resource-configs/redshift-configs.md @@ -264,7 +264,7 @@ The workaround is to execute `DROP MATERIALIZED VIEW my_mv CASCADE` on the data Redshift doesn't support Unit tests when the SQL in the common table expression (CTE) contains functions such as `LISTAGG`, `MEDIAN`, `PERCENTILE_CONT`, etc. These functions must be executed against a user-created table. dbt combines given rows to be part of the CTE, which Redshift does not support. For unit tests to function properly in this scenario, creating temporary tables for the unit tests to reference is a good workaround. -The following query illustrates this limitation: +The following query illustrates the limitation: ```sql