diff --git a/udfs/community/README.md b/udfs/community/README.md index ec4f6a7fe..c9f1adf82 100644 --- a/udfs/community/README.md +++ b/udfs/community/README.md @@ -72,7 +72,13 @@ SELECT bqutil.fn.int(1.684) * [cw_parse_timestamp](#cw_parse_timestamptimeString-string-formatString-string) * [cw_period_intersection](#cw_period_intersectionp1-structlower-timestamp-upper-timestamp-p2-structlower-timestamp-upper-timestamp) * [cw_period_ldiff](#cw_period_ldiffp1-structlower-timestamp-upper-timestamp-p2-structlower-timestamp-upper-timestamp) +* [cw_range_date_ldiff](#cw_range_date_ldiffp1-range-p2-range) +* [cw_range_datetime_ldiff](#cw_range_datetime_ldiffp1-range-p2-range) +* [cw_range_timestamp_ldiff](#cw_range_timestamp_ldiffp1-range-p2-range) * [cw_period_rdiff](#cw_period_rdiffp1-structlower-timestamp-upper-timestamp-p2-structlower-timestamp-upper-timestamp) +* [cw_range_date_rdiff](#cw_range_date_rdiffp1-range-p2-range) +* [cw_range_datetime_rdiff](#cw_range_datetime_rdiffp1-range-p2-range) +* [cw_range_timestamp_rdiff](#cw_range_timestamp_rdiffp1-range-p2-range) * [cw_regex_mode](#cw_regex_modemode-string) * [cw_regexp_extract](#cw_regexp_extractstr-string-regexp-string) * [cw_regexp_extract_all](#cw_regexp_extract_allstr-string-regexp-string) @@ -784,6 +790,33 @@ SELECT bqutil.fn.cw_period_ldiff( STRUCT(TIMESTAMP '2001-11-12 00:00:00' AS lower, TIMESTAMP '2001-11-13 00:00:00' AS upper) ``` +### [cw_range_date_ldiff(p1 RANGE, p2 RANGE)](cw_range_date_ldiff.sqlx) +```sql +SELECT cw_udf.cw_range_date_ldiff( + RANGE(DATE '2001-11-12', DATE '2001-11-14'), + RANGE(DATE '2001-11-13', DATE '2001-11-15')) + +RANGE(DATE '2001-11-12', DATE '2001-11-13') +``` + +### [cw_range_datetime_ldiff(p1 RANGE, p2 RANGE)](cw_range_datetime_ldiff.sqlx) +```sql +SELECT cw_udf.cw_range_datetime_ldiff( + RANGE(DATETIME '2001-11-12 00:00:00', DATETIME '2001-11-14 00:00:00'), + RANGE(DATETIME '2001-11-13 00:00:00', DATETIME '2001-11-15 00:00:00')) + +RANGE(DATETIME '2001-11-12 00:00:00', DATETIME '2001-11-13 00:00:00') +``` + +### [cw_range_timestamp_ldiff(p1 RANGE, p2 RANGE)](cw_range_timestamp_ldiff.sqlx) +```sql +SELECT cw_udf.cw_range_timestamp_ldiff( + RANGE(TIMESTAMP '2001-11-12 00:00:00', TIMESTAMP '2001-11-14 00:00:00'), + RANGE(TIMESTAMP '2001-11-13 00:00:00', TIMESTAMP '2001-11-15 00:00:00')) + +RANGE(TIMESTAMP '2001-11-12 00:00:00', TIMESTAMP '2001-11-13 00:00:00') +``` + ### [cw_period_rdiff(p1 STRUCT, p2 STRUCT)](cw_period_rdiff.sqlx) ```sql SELECT bqutil.fn.cw_period_rdiff( @@ -793,6 +826,34 @@ SELECT bqutil.fn.cw_period_rdiff( STRUCT(TIMESTAMP '2001-11-14 00:00:00' AS lower, TIMESTAMP '2001-11-15 00:00:00' AS upper) ``` +### [cw_range_date_rdiff(p1 RANGE, p2 RANGE)](cw_range_date_rdiff.sqlx) +```sql +SELECT cw_udf.cw_range_date_rdiff( + RANGE(DATE '2001-11-13', DATE '2001-11-15'), + RANGE(DATE '2001-11-12', DATE '2001-11-14')) + +RANGE(DATE '2001-11-14', DATE '2001-11-15') +``` + +### [cw_range_datetime_rdiff(p1 RANGE, p2 RANGE)](cw_range_datetime_rdiff.sqlx) +```sql +SELECT cw_udf.cw_range_datetime_rdiff( + RANGE(DATETIME '2001-11-13 00:00:00', DATETIME '2001-11-15 00:00:00'), + RANGE(DATETIME '2001-11-12 00:00:00', DATETIME '2001-11-14 00:00:00')) + +RANGE(DATETIME '2001-11-14 00:00:00', DATETIME '2001-11-15 00:00:00') +``` + + +### [cw_range_timestamp_rdiff(p1 RANGE, p2 RANGE)](cw_range_timestamp_rdiff.sqlx) +```sql +SELECT cw_udf.cw_range_timestamp_rdiff( + RANGE(TIMESTAMP '2001-11-13 00:00:00', TIMESTAMP '2001-11-15 00:00:00'), + RANGE(TIMESTAMP '2001-11-12 00:00:00', TIMESTAMP '2001-11-14 00:00:00')) + +RANGE(TIMESTAMP '2001-11-14 00:00:00', TIMESTAMP '2001-11-15 00:00:00') +``` + ### [cw_regex_mode(mode STRING)](cw_regex_mode.sqlx) Retrieve mode. ```sql diff --git a/udfs/community/cw_range_date_ldiff.sqlx b/udfs/community/cw_range_date_ldiff.sqlx new file mode 100644 index 000000000..9a28c67cd --- /dev/null +++ b/udfs/community/cw_range_date_ldiff.sqlx @@ -0,0 +1,26 @@ +config { hasOutput: true } +/* + * Copyright 2026 Google LLC + * + * Licensed under the Apache License, Version 2.0 (the "License"); + * you may not use this file except in compliance with the License. + * You may obtain a copy of the License at + * + * http://www.apache.org/licenses/LICENSE-2.0 + * + * Unless required by applicable law or agreed to in writing, software + * distributed under the License is distributed on an "AS IS" BASIS, + * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + * See the License for the specific language governing permissions and + * limitations under the License. + */ + +CREATE OR REPLACE FUNCTION ${self()}(p1 RANGE, p2 RANGE) RETURNS RANGE +OPTIONS(description="Emulates Teradata's LDIFF operator with RANGE inputs.") +AS ( + CASE + WHEN RANGE_OVERLAPS(p1, p2) AND RANGE_START(p1) < RANGE_START(p2) THEN + RANGE(RANGE_START(p1), RANGE_START(p2)) + ELSE NULL + END +); diff --git a/udfs/community/cw_range_date_rdiff.sqlx b/udfs/community/cw_range_date_rdiff.sqlx new file mode 100644 index 000000000..c256ec6f5 --- /dev/null +++ b/udfs/community/cw_range_date_rdiff.sqlx @@ -0,0 +1,26 @@ +config { hasOutput: true } +/* + * Copyright 2026 Google LLC + * + * Licensed under the Apache License, Version 2.0 (the "License"); + * you may not use this file except in compliance with the License. + * You may obtain a copy of the License at + * + * http://www.apache.org/licenses/LICENSE-2.0 + * + * Unless required by applicable law or agreed to in writing, software + * distributed under the License is distributed on an "AS IS" BASIS, + * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + * See the License for the specific language governing permissions and + * limitations under the License. + */ + +CREATE OR REPLACE FUNCTION ${self()}(p1 RANGE, p2 RANGE) RETURNS RANGE +OPTIONS(description="Emulates Teradata's RDIFF operator with RANGE inputs.") +AS ( + CASE + WHEN RANGE_OVERLAPS(p1, p2) AND RANGE_END(p1) > RANGE_END(p2) THEN + RANGE(RANGE_END(p2), RANGE_END(p1)) + ELSE NULL + END +); diff --git a/udfs/community/cw_range_datetime_ldiff.sqlx b/udfs/community/cw_range_datetime_ldiff.sqlx new file mode 100644 index 000000000..848894f47 --- /dev/null +++ b/udfs/community/cw_range_datetime_ldiff.sqlx @@ -0,0 +1,26 @@ +config { hasOutput: true } +/* + * Copyright 2026 Google LLC + * + * Licensed under the Apache License, Version 2.0 (the "License"); + * you may not use this file except in compliance with the License. + * You may obtain a copy of the License at + * + * http://www.apache.org/licenses/LICENSE-2.0 + * + * Unless required by applicable law or agreed to in writing, software + * distributed under the License is distributed on an "AS IS" BASIS, + * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + * See the License for the specific language governing permissions and + * limitations under the License. + */ + +CREATE OR REPLACE FUNCTION ${self()}(p1 RANGE, p2 RANGE) RETURNS RANGE +OPTIONS(description="Emulates Teradata's LDIFF operator with RANGE inputs.") +AS ( + CASE + WHEN RANGE_OVERLAPS(p1, p2) AND RANGE_START(p1) < RANGE_START(p2) THEN + RANGE(RANGE_START(p1), RANGE_START(p2)) + ELSE NULL + END +); diff --git a/udfs/community/cw_range_datetime_rdiff.sqlx b/udfs/community/cw_range_datetime_rdiff.sqlx new file mode 100644 index 000000000..c68a85e6f --- /dev/null +++ b/udfs/community/cw_range_datetime_rdiff.sqlx @@ -0,0 +1,26 @@ +config { hasOutput: true } +/* + * Copyright 2026 Google LLC + * + * Licensed under the Apache License, Version 2.0 (the "License"); + * you may not use this file except in compliance with the License. + * You may obtain a copy of the License at + * + * http://www.apache.org/licenses/LICENSE-2.0 + * + * Unless required by applicable law or agreed to in writing, software + * distributed under the License is distributed on an "AS IS" BASIS, + * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + * See the License for the specific language governing permissions and + * limitations under the License. + */ + +CREATE OR REPLACE FUNCTION ${self()}(p1 RANGE, p2 RANGE) RETURNS RANGE +OPTIONS(description="Emulates Teradata's RDIFF operator with RANGE inputs.") +AS ( + CASE + WHEN RANGE_OVERLAPS(p1, p2) AND RANGE_END(p1) > RANGE_END(p2) THEN + RANGE(RANGE_END(p2), RANGE_END(p1)) + ELSE NULL + END +); diff --git a/udfs/community/cw_range_timestamp_ldiff.sqlx b/udfs/community/cw_range_timestamp_ldiff.sqlx new file mode 100644 index 000000000..c603da465 --- /dev/null +++ b/udfs/community/cw_range_timestamp_ldiff.sqlx @@ -0,0 +1,26 @@ +config { hasOutput: true } +/* + * Copyright 2026 Google LLC + * + * Licensed under the Apache License, Version 2.0 (the "License"); + * you may not use this file except in compliance with the License. + * You may obtain a copy of the License at + * + * http://www.apache.org/licenses/LICENSE-2.0 + * + * Unless required by applicable law or agreed to in writing, software + * distributed under the License is distributed on an "AS IS" BASIS, + * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + * See the License for the specific language governing permissions and + * limitations under the License. + */ + +CREATE OR REPLACE FUNCTION ${self()}(p1 RANGE, p2 RANGE) RETURNS RANGE +OPTIONS(description="Emulates Teradata's LDIFF operator with RANGE inputs.") +AS ( + CASE + WHEN RANGE_OVERLAPS(p1, p2) AND RANGE_START(p1) < RANGE_START(p2) THEN + RANGE(RANGE_START(p1), RANGE_START(p2)) + ELSE NULL + END +); diff --git a/udfs/community/cw_range_timestamp_rdiff.sqlx b/udfs/community/cw_range_timestamp_rdiff.sqlx new file mode 100644 index 000000000..a0af5485c --- /dev/null +++ b/udfs/community/cw_range_timestamp_rdiff.sqlx @@ -0,0 +1,26 @@ +config { hasOutput: true } +/* + * Copyright 2026 Google LLC + * + * Licensed under the Apache License, Version 2.0 (the "License"); + * you may not use this file except in compliance with the License. + * You may obtain a copy of the License at + * + * http://www.apache.org/licenses/LICENSE-2.0 + * + * Unless required by applicable law or agreed to in writing, software + * distributed under the License is distributed on an "AS IS" BASIS, + * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + * See the License for the specific language governing permissions and + * limitations under the License. + */ + +CREATE OR REPLACE FUNCTION ${self()}(p1 RANGE, p2 RANGE) RETURNS RANGE +OPTIONS(description="Emulates Teradata's RDIFF operator with RANGE inputs.") +AS ( + CASE + WHEN RANGE_OVERLAPS(p1, p2) AND RANGE_END(p1) > RANGE_END(p2) THEN + RANGE(RANGE_END(p2), RANGE_END(p1)) + ELSE NULL + END +); diff --git a/udfs/community/test_cases.js b/udfs/community/test_cases.js index a5f3168d5..b25950735 100644 --- a/udfs/community/test_cases.js +++ b/udfs/community/test_cases.js @@ -3148,6 +3148,96 @@ generate_udf_test("cw_period_ldiff", [ expected_output: `NULL`, }, ]); +generate_udf_test("cw_range_date_ldiff", [ + { + inputs: [ + `RANGE '[2001-11-12, 2001-11-14)'`, + `RANGE '[2001-11-13, 2001-11-15)'`, + ], + expected_output: `RANGE '[2001-11-12, 2001-11-13)'`, + }, + { + inputs: [ + `RANGE '[2001-11-22, 2001-11-26)'`, + `RANGE '[2001-11-23, 2001-11-25)'`, + ], + expected_output: `RANGE '[2001-11-22, 2001-11-23)'`, + }, + { + inputs: [ + `RANGE '[2001-11-13, 2001-11-14)'`, + `RANGE '[2001-11-15, 2001-11-16)'`, + ], + expected_output: `NULL`, + }, + { + inputs: [ + `RANGE '[2001-11-12, 2001-11-14)'`, + `RANGE '[2001-11-14, 2001-11-15)'`, + ], + expected_output: `NULL`, + }, +]); +generate_udf_test("cw_range_datetime_ldiff", [ + { + inputs: [ + `RANGE '[2001-11-12 00:00:00, 2001-11-14 00:00:00)'`, + `RANGE '[2001-11-13 00:00:00, 2001-11-15 00:00:00)'`, + ], + expected_output: `RANGE '[2001-11-12 00:00:00, 2001-11-13 00:00:00)'`, + }, + { + inputs: [ + `RANGE '[2001-11-22 00:00:00, 2001-11-26 00:00:00)'`, + `RANGE '[2001-11-23 00:00:00, 2001-11-25 00:00:00)'`, + ], + expected_output: `RANGE '[2001-11-22 00:00:00, 2001-11-23 00:00:00)'`, + }, + { + inputs: [ + `RANGE '[2001-11-13 00:00:00, 2001-11-14 00:00:00)'`, + `RANGE '[2001-11-15 00:00:00, 2001-11-16 00:00:00)'`, + ], + expected_output: `NULL`, + }, + { + inputs: [ + `RANGE '[2001-11-12 00:00:00, 2001-11-14 00:00:00)'`, + `RANGE '[2001-11-14 00:00:00, 2001-11-15 00:00:00)'`, + ], + expected_output: `NULL`, + }, +]); +generate_udf_test("cw_range_timestamp_ldiff", [ + { + inputs: [ + `RANGE '[2001-11-12 00:00:00, 2001-11-14 00:00:00)'`, + `RANGE '[2001-11-13 00:00:00, 2001-11-15 00:00:00)'`, + ], + expected_output: `RANGE '[2001-11-12 00:00:00, 2001-11-13 00:00:00)'`, + }, + { + inputs: [ + `RANGE '[2001-11-22 00:00:00, 2001-11-26 00:00:00)'`, + `RANGE '[2001-11-23 00:00:00, 2001-11-25 00:00:00)'`, + ], + expected_output: `RANGE '[2001-11-22 00:00:00, 2001-11-23 00:00:00)'`, + }, + { + inputs: [ + `RANGE '[2001-11-13 00:00:00, 2001-11-14 00:00:00)'`, + `RANGE '[2001-11-15 00:00:00, 2001-11-16 00:00:00)'`, + ], + expected_output: `NULL`, + }, + { + inputs: [ + `RANGE '[2001-11-12 00:00:00, 2001-11-14 00:00:00)'`, + `RANGE '[2001-11-14 00:00:00, 2001-11-15 00:00:00)'`, + ], + expected_output: `NULL`, + }, +]); generate_udf_test("cw_period_rdiff", [ { inputs: [ @@ -3178,6 +3268,96 @@ generate_udf_test("cw_period_rdiff", [ expected_output: `NULL`, }, ]); +generate_udf_test("cw_range_date_rdiff", [ + { + inputs: [ + `RANGE '[2001-11-13, 2001-11-15)'`, + `RANGE '[2001-11-12, 2001-11-14)'`, + ], + expected_output: `RANGE '[2001-11-14, 2001-11-15)'`, + }, + { + inputs: [ + `RANGE '[2001-11-22, 2001-11-26)'`, + `RANGE '[2001-11-23, 2001-11-25)'`, + ], + expected_output: `RANGE '[2001-11-25, 2001-11-26)'`, + }, + { + inputs: [ + `RANGE '[2001-11-15, 2001-11-16)'`, + `RANGE '[2001-11-13, 2001-11-14)'`, + ], + expected_output: `NULL`, + }, + { + inputs: [ + `RANGE '[2001-11-14, 2001-11-15)'`, + `RANGE '[2001-11-12, 2001-11-14)'`, + ], + expected_output: `NULL`, + }, +]); +generate_udf_test("cw_range_datetime_rdiff", [ + { + inputs: [ + `RANGE '[2001-11-13 00:00:00, 2001-11-15 00:00:00)'`, + `RANGE '[2001-11-12 00:00:00, 2001-11-14 00:00:00)'`, + ], + expected_output: `RANGE '[2001-11-14 00:00:00, 2001-11-15 00:00:00)'`, + }, + { + inputs: [ + `RANGE '[2001-11-22 00:00:00, 2001-11-26 00:00:00)'`, + `RANGE '[2001-11-23 00:00:00, 2001-11-25 00:00:00)'`, + ], + expected_output: `RANGE '[2001-11-25 00:00:00, 2001-11-26 00:00:00)'`, + }, + { + inputs: [ + `RANGE '[2001-11-15 00:00:00, 2001-11-16 00:00:00)'`, + `RANGE '[2001-11-13 00:00:00, 2001-11-14 00:00:00)'`, + ], + expected_output: `NULL`, + }, + { + inputs: [ + `RANGE '[2001-11-14 00:00:00, 2001-11-15 00:00:00)'`, + `RANGE '[2001-11-12 00:00:00, 2001-11-14 00:00:00)'`, + ], + expected_output: `NULL`, + }, +]); +generate_udf_test("cw_range_timestamp_rdiff", [ + { + inputs: [ + `RANGE '[2001-11-13 00:00:00, 2001-11-15 00:00:00)'`, + `RANGE '[2001-11-12 00:00:00, 2001-11-14 00:00:00)'`, + ], + expected_output: `RANGE '[2001-11-14 00:00:00, 2001-11-15 00:00:00)'`, + }, + { + inputs: [ + `RANGE '[2001-11-22 00:00:00, 2001-11-26 00:00:00)'`, + `RANGE '[2001-11-23 00:00:00, 2001-11-25 00:00:00)'`, + ], + expected_output: `RANGE '[2001-11-25 00:00:00, 2001-11-26 00:00:00)'`, + }, + { + inputs: [ + `RANGE '[2001-11-15 00:00:00, 2001-11-16 00:00:00)'`, + `RANGE '[2001-11-13 00:00:00, 2001-11-14 00:00:00)'`, + ], + expected_output: `NULL`, + }, + { + inputs: [ + `RANGE '[2001-11-14 00:00:00, 2001-11-15 00:00:00)'`, + `RANGE '[2001-11-12 00:00:00, 2001-11-14 00:00:00)'`, + ], + expected_output: `NULL`, + }, +]); generate_udf_test("cw_split_part_delimstr_idx", [ { inputs: [`"foo bar baz"`, `" "`, `1`],