From 7bda69676d5e96ca4349038c25143c3c09393300 Mon Sep 17 00:00:00 2001 From: Zijie Date: Thu, 18 Jul 2024 20:51:44 +0800 Subject: [PATCH] Add regexp_not_like() for orafce and fix test --- gpcontrib/orafce/expected/gp_partition_by.out | 2 ++ gpcontrib/orafce/orafce--4.8--4.9.sql | 34 +++++++++++++++++++ gpcontrib/orafce/orafce--4.9.sql | 34 +++++++++++++++++++ gpcontrib/orafce/sql/gp_partition_by.sql | 2 ++ 4 files changed, 72 insertions(+) diff --git a/gpcontrib/orafce/expected/gp_partition_by.out b/gpcontrib/orafce/expected/gp_partition_by.out index 0409cdc4b55..9141824f364 100644 --- a/gpcontrib/orafce/expected/gp_partition_by.out +++ b/gpcontrib/orafce/expected/gp_partition_by.out @@ -9,6 +9,7 @@ CREATE TABLE t3 ( NOTICE: Table doesn't have 'DISTRIBUTED BY' clause -- Using column named 'str' as the Greenplum Database data distribution key for this table. HINT: The 'DISTRIBUTED BY' clause determines the distribution of data. Make sure column(s) chosen are the optimal data distribution key to minimize skew. INSERT INTO t3 VALUES ('a'), ('b'), ('c'); +ANALYZE t3; SELECT * FROM t3 ORDER BY str; str ----- @@ -37,6 +38,7 @@ CREATE TABLE t4 ( NOTICE: Table doesn't have 'DISTRIBUTED BY' clause -- Using column named 'str' as the Greenplum Database data distribution key for this table. HINT: The 'DISTRIBUTED BY' clause determines the distribution of data. Make sure column(s) chosen are the optimal data distribution key to minimize skew. INSERT INTO t4 VALUES ('a'), ('b'), ('c'); +ANALYZE t4; SELECT * FROM t4 ORDER BY str; str ----- diff --git a/gpcontrib/orafce/orafce--4.8--4.9.sql b/gpcontrib/orafce/orafce--4.8--4.9.sql index dec698ae858..d424e6440ad 100644 --- a/gpcontrib/orafce/orafce--4.8--4.9.sql +++ b/gpcontrib/orafce/orafce--4.8--4.9.sql @@ -175,3 +175,37 @@ END; $$ LANGUAGE plpgsql STRICT IMMUTABLE PARALLEL SAFE; +-- Add regexp_not_like based on regexp_like + +-- REGEXP_NOT_LIKE( string text, pattern text) -> boolean +-- If one of the param is NULL returns NULL, declared STRICT +CREATE OR REPLACE FUNCTION oracle.regexp_not_like(text, text) +RETURNS boolean +AS $$ + -- Oracle default behavior is newline-sensitive, + -- PostgreSQL not, so force 'p' modifier to affect + -- newline-sensitivity but not ^ and $ search. + SELECT CASE WHEN (count(*) > 0) THEN false ELSE true END FROM regexp_matches($1, $2, 'p'); +$$ +LANGUAGE 'sql' STRICT; + +-- REGEXP_NOT_LIKE( string text, pattern text, flags text ) -> boolean +CREATE OR REPLACE FUNCTION oracle.regexp_not_like(text, text, text) +RETURNS boolean +AS $$ +DECLARE + modifiers text; +BEGIN + -- Only modifier can be NULL + IF $1 IS NULL OR $2 IS NULL THEN + RETURN NULL; + END IF; + modifiers := oracle.translate_oracle_modifiers($3, false); + IF (regexp_matches($1, $2, modifiers))[1] IS NOT NULL THEN + RETURN false; + END IF; + RETURN true; +END; +$$ +LANGUAGE plpgsql; + diff --git a/gpcontrib/orafce/orafce--4.9.sql b/gpcontrib/orafce/orafce--4.9.sql index fbfe8a96c34..fd1571581ad 100644 --- a/gpcontrib/orafce/orafce--4.9.sql +++ b/gpcontrib/orafce/orafce--4.9.sql @@ -4012,6 +4012,40 @@ RETURNS text AS 'MODULE_PATHNAME','orafce_textregexreplace' LANGUAGE 'c' IMMUTABLE PARALLEL SAFE; +-- Add regexp_not_like based on regexp_like + +-- REGEXP_NOT_LIKE( string text, pattern text) -> boolean +-- If one of the param is NULL returns NULL, declared STRICT +CREATE OR REPLACE FUNCTION oracle.regexp_not_like(text, text) +RETURNS boolean +AS $$ + -- Oracle default behavior is newline-sensitive, + -- PostgreSQL not, so force 'p' modifier to affect + -- newline-sensitivity but not ^ and $ search. + SELECT CASE WHEN (count(*) > 0) THEN false ELSE true END FROM regexp_matches($1, $2, 'p'); +$$ +LANGUAGE 'sql' STRICT; + +-- REGEXP_NOT_LIKE( string text, pattern text, flags text ) -> boolean +CREATE OR REPLACE FUNCTION oracle.regexp_not_like(text, text, text) +RETURNS boolean +AS $$ +DECLARE + modifiers text; +BEGIN + -- Only modifier can be NULL + IF $1 IS NULL OR $2 IS NULL THEN + RETURN NULL; + END IF; + modifiers := oracle.translate_oracle_modifiers($3, false); + IF (regexp_matches($1, $2, modifiers))[1] IS NOT NULL THEN + RETURN false; + END IF; + RETURN true; +END; +$$ +LANGUAGE plpgsql; + ---- -- Add LEAST/GREATEST declaration to return NULL on NULL input. -- PostgreSQL only returns NULL when all the parameters are NULL. diff --git a/gpcontrib/orafce/sql/gp_partition_by.sql b/gpcontrib/orafce/sql/gp_partition_by.sql index f99a0f614a8..bbfa8e4b739 100644 --- a/gpcontrib/orafce/sql/gp_partition_by.sql +++ b/gpcontrib/orafce/sql/gp_partition_by.sql @@ -7,6 +7,7 @@ CREATE TABLE t3 ( PARTITION t3_2 VALUES ('c') ); INSERT INTO t3 VALUES ('a'), ('b'), ('c'); +ANALYZE t3; SELECT * FROM t3 ORDER BY str; \d+ t3 @@ -18,6 +19,7 @@ CREATE TABLE t4 ( PARTITION t4_2 VALUES ('c') ); INSERT INTO t4 VALUES ('a'), ('b'), ('c'); +ANALYZE t4; SELECT * FROM t4 ORDER BY str; \d+ t4