Skip to content

Commit

Permalink
workable release for PostgreSQL 15
Browse files Browse the repository at this point in the history
  • Loading branch information
okbob committed Apr 13, 2022
1 parent 219c7f0 commit 12b4403
Show file tree
Hide file tree
Showing 5 changed files with 587 additions and 152 deletions.
5 changes: 5 additions & 0 deletions builtins.h
Original file line number Diff line number Diff line change
Expand Up @@ -303,5 +303,10 @@ extern PGDLLEXPORT Datum orafce_regexp_instr_no_n(PG_FUNCTION_ARGS);
extern PGDLLEXPORT Datum orafce_regexp_instr_no_endoption(PG_FUNCTION_ARGS);
extern PGDLLEXPORT Datum orafce_regexp_instr_no_flags(PG_FUNCTION_ARGS);
extern PGDLLEXPORT Datum orafce_regexp_instr_no_subexpr(PG_FUNCTION_ARGS);
extern PGDLLEXPORT Datum orafce_textregexreplace_noopt(PG_FUNCTION_ARGS);
extern PGDLLEXPORT Datum orafce_textregexreplace(PG_FUNCTION_ARGS);
extern PGDLLEXPORT Datum orafce_textregexreplace_extended(PG_FUNCTION_ARGS);
extern PGDLLEXPORT Datum orafce_textregexreplace_extended_no_n(PG_FUNCTION_ARGS);
extern PGDLLEXPORT Datum orafce_textregexreplace_extended_no_flags(PG_FUNCTION_ARGS);

#endif
38 changes: 21 additions & 17 deletions expected/regexp_func.out
Original file line number Diff line number Diff line change
Expand Up @@ -575,32 +575,32 @@ SELECT REGEXP_REPLACE('512.123.4567', '([[:digit:]]{3})\.([[:digit:]]{3})\.([[:d

-- ORACLE> SELECT REGEXP_REPLACE('512.123.4567 612.123.4567', '([[:digit:]]{3})\.([[:digit:]]{3})\.([[:digit:]]{4})', '(\1) \2-\3') FROM DUAL; -> (512) 123-4567 (612) 123-4567
SELECT oracle.REGEXP_REPLACE('512.123.4567 612.123.4567', '([[:digit:]]{3})\.([[:digit:]]{3})\.([[:digit:]]{4})', '(\1) \2-\3');
regexp_replace
-------------------------------
(512) 123-4567 (612) 123-4567
regexp_replace
-----------------------------
(512) 123-4567 612.123.4567
(1 row)

-- ORACLE> SELECT REGEXP_REPLACE('number your street, zipcode town, FR', '( ){2,}', ' ') FROM DUAL; -> number your street, zipcode town, FR
SELECT oracle.REGEXP_REPLACE('number your street, zipcode town, FR', '( ){2,}', ' ');
regexp_replace
--------------------------------------
number your street, zipcode town, FR
regexp_replace
----------------------------------------------
number your street, zipcode town, FR
(1 row)

-- ORACLE> SELECT REGEXP_REPLACE('number your street,'||CHR(10)||' zipcode town, FR', '( ){2,}', ' ') FROM DUAL; -> number your street,
-- zipcode town, FR
SELECT oracle.REGEXP_REPLACE('number your street,'||CHR(10)||' zipcode town, FR', '( ){2,}', ' ');
regexp_replace
---------------------
number your street,+
zipcode town, FR
regexp_replace
-------------------------
number your street,+
zipcode town, FR
(1 row)

-- ORACLE> SELECT REGEXP_REPLACE('number your street, zipcode town, FR', '( ){2,}', ' ', 9) FROM DUAL; -> number your street, zipcode town, FR
SELECT oracle.REGEXP_REPLACE('number your street, zipcode town, FR', '( ){2,}', ' ', 9);
regexp_replace
----------------------------------------
number your street, zipcode town, FR
regexp_replace
--------------------------------------------
number your street, zipcode town, FR
(1 row)

-- ORACLE> SELECT REGEXP_REPLACE('number your street, zipcode town, FR', '( ){2,}', ' ', 9, 0) FROM DUAL; -> number your street, zipcode town, FR
Expand Down Expand Up @@ -695,7 +695,11 @@ SELECT oracle.REGEXP_REPLACE ('A PostgreSQL function', 'a|e|i|o|u', 'X', 1, -1,
ERROR: argument 'occurrence' must be a positive number
-- ORACLE> SELECT REGEXP_REPLACE ('A PostgreSQL function', 'a|e|i|o|u', 'X', 1, 1, 'g') FROM DUAL; -> ORA-01760
SELECT oracle.REGEXP_REPLACE ('A PostgreSQL function', 'a|e|i|o|u', 'X', 1, 1, 'g');
ERROR: argument 'flags' has unsupported modifier(s).
regexp_replace
-----------------------
A PXstgreSQL function
(1 row)

--
-- Test NULL input in the regexp_* functions that must returned NULL except for the modifier
-- or regexp flag. There is an exception with regexp_replace(), if the pattern is null (second
Expand Down Expand Up @@ -892,7 +896,7 @@ SELECT oracle.REGEXP_REPLACE('1234', '\d', null);
SELECT oracle.REGEXP_REPLACE('1234', '\d', 'a', null);
regexp_replace
----------------

a234
(1 row)

SELECT oracle.REGEXP_REPLACE('1234', null, 'a', 2);
Expand All @@ -904,7 +908,7 @@ SELECT oracle.REGEXP_REPLACE('1234', null, 'a', 2);
SELECT oracle.REGEXP_REPLACE('1234', null, 'a', null);
regexp_replace
----------------

1234
(1 row)

SELECT oracle.REGEXP_REPLACE('1234', null, 'a', 1);
Expand All @@ -916,7 +920,7 @@ SELECT oracle.REGEXP_REPLACE('1234', null, 'a', 1);
SELECT oracle.REGEXP_REPLACE('1234', null, 'a', 1, null);
regexp_replace
----------------

1234
(1 row)

SELECT oracle.REGEXP_REPLACE('1234', '\d', 'a', 1, null);
Expand Down
29 changes: 29 additions & 0 deletions orafce--3.20--3.21.sql
Original file line number Diff line number Diff line change
Expand Up @@ -33,3 +33,32 @@ CREATE OR REPLACE FUNCTION oracle.regexp_instr(text, text, integer, integer, int
RETURNS integer
AS 'MODULE_PATHNAME','orafce_regexp_instr'
LANGUAGE 'c' IMMUTABLE;

-- REGEXP_REPLACE( string text, pattern text, replace_string text ) -> text
CREATE OR REPLACE FUNCTION oracle.regexp_replace(text, text, text)
RETURNS text
AS 'MODULE_PATHNAME','orafce_textregexreplace_noopt'
LANGUAGE 'c' IMMUTABLE;

-- REGEXP_REPLACE( string text, pattern text, replace_string text, position int ) -> text
CREATE OR REPLACE FUNCTION oracle.regexp_replace(text, text, text, integer)
RETURNS text
AS 'MODULE_PATHNAME','orafce_textregexreplace_extended_no_n'
LANGUAGE 'c' IMMUTABLE;

-- REGEXP_REPLACE( string text, pattern text, replace_string text, position int, occurence int ) -> text
CREATE OR REPLACE FUNCTION oracle.regexp_replace(text, text, text, integer, integer)
RETURNS text
AS 'MODULE_PATHNAME','orafce_textregexreplace_extended_no_flags'
LANGUAGE 'c' IMMUTABLE;

-- REGEXP_REPLACE( string text, pattern text, replace_string text, position int, occurence int, flags text ) -> text
CREATE OR REPLACE FUNCTION oracle.regexp_replace(text, text, text, integer, integer, text)
RETURNS text
AS 'MODULE_PATHNAME','orafce_textregexreplace_extended'
LANGUAGE 'c' IMMUTABLE;

CREATE OR REPLACE FUNCTION oracle.regexp_replace(text, text, text, text)
RETURNS text
AS 'MODULE_PATHNAME','orafce_textregexreplace'
LANGUAGE 'c' IMMUTABLE;
148 changes: 13 additions & 135 deletions orafce--3.21.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3884,153 +3884,31 @@ LANGUAGE plpgsql;
-- REGEXP_REPLACE( string text, pattern text, replace_string text ) -> text
CREATE OR REPLACE FUNCTION oracle.regexp_replace(text, text, text)
RETURNS text
AS $$
DECLARE
str text;
BEGIN
IF $2 IS NULL AND $1 IS NOT NULL THEN
RETURN $1;
END IF;
-- Oracle default behavior is to replace all occurence
-- whereas PostgreSQL only replace the first occurrence
-- so we need to add 'g' modifier.
SELECT pg_catalog.regexp_replace($1, $2, $3, 'g') INTO str;
RETURN str;
END;
$$
LANGUAGE plpgsql;
AS 'MODULE_PATHNAME','orafce_textregexreplace_noopt'
LANGUAGE 'c' IMMUTABLE;

-- REGEXP_REPLACE( string text, pattern text, replace_string text, position int ) -> text
CREATE OR REPLACE FUNCTION oracle.regexp_replace(text, text, text, integer)
RETURNS text
AS $$
DECLARE
v_replaced_str text;
v_before text;
BEGIN
IF $1 IS NULL OR $3 IS NULL OR $4 IS NULL THEN
RETURN NULL;
END IF;
IF $2 IS NULL THEN
RETURN $1;
END IF;
-- Check numeric arguments
IF $4 < 1 THEN
RAISE EXCEPTION 'argument ''position'' must be a number greater than 0';
END IF;

v_before = substr($1, 1, $4 - 1);

-- Oracle default behavior is to replace all occurence
-- whereas PostgreSQL only replace the first occurrence
-- so we need to add 'g' modifier.
v_replaced_str := v_before || pg_catalog.regexp_replace(substr($1, $4), $2, $3, 'g');
RETURN v_replaced_str;
END;
$$
LANGUAGE plpgsql;
AS 'MODULE_PATHNAME','orafce_textregexreplace_extended_no_n'
LANGUAGE 'c' IMMUTABLE;

-- REGEXP_REPLACE( string text, pattern text, replace_string text, position int, occurence int ) -> text
CREATE OR REPLACE FUNCTION oracle.regexp_replace(text, text, text, integer, integer)
RETURNS text
AS $$
DECLARE
v_replaced_str text;
v_pos integer := $4;
v_before text := '';
v_nummatch integer;
BEGIN
IF $1 IS NULL OR $3 IS NULL OR $4 IS NULL OR $5 IS NULL THEN
RETURN NULL;
END IF;
IF $2 IS NULL THEN
RETURN $1;
END IF;
-- Check numeric arguments
IF $4 < 1 THEN
RAISE EXCEPTION 'argument ''position'' must be a number greater than 0';
END IF;
IF $5 < 0 THEN
RAISE EXCEPTION 'argument ''occurrence'' must be a positive number';
END IF;
-- Check if the occurrence queried exceeds the number of occurrences
IF $5 > 1 THEN
v_nummatch := (SELECT count(*) FROM regexp_matches(substr($1, $4), $2, 'g'));
IF $5 > v_nummatch THEN
RETURN $1;
END IF;
-- Get the position of the occurrence we are looking for
v_pos := oracle.regexp_instr($1, $2, $4, $5, 0, '', 1);
IF v_pos = 0 THEN
RETURN $1;
END IF;
END IF;
-- Get the substring before this position we will need to restore it
v_before := substr($1, 1, v_pos - 1);

-- Replace all occurrences
IF $5 = 0 THEN
v_replaced_str := v_before || pg_catalog.regexp_replace(substr($1, v_pos), $2, $3, 'g');
ELSE
-- Replace the first occurrence
v_replaced_str := v_before || pg_catalog.regexp_replace(substr($1, v_pos), $2, $3);
END IF;

RETURN v_replaced_str;
END;
$$
LANGUAGE plpgsql;
AS 'MODULE_PATHNAME','orafce_textregexreplace_extended_no_flags'
LANGUAGE 'c' IMMUTABLE;

-- REGEXP_REPLACE( string text, pattern text, replace_string text, position int, occurence int, flags text ) -> text
CREATE OR REPLACE FUNCTION oracle.regexp_replace(text, text, text, integer, integer, text)
RETURNS text
AS $$
DECLARE
v_replaced_str text;
v_pos integer := $4;
v_nummatch integer;
v_before text := '';
modifiers text := '';
BEGIN
IF $1 IS NULL OR $3 IS NULL OR $4 IS NULL OR $5 IS NULL THEN
RETURN NULL;
END IF;
IF $2 IS NULL THEN
RETURN $1;
END IF;
-- Check numeric arguments
IF $4 < 1 THEN
RAISE EXCEPTION 'argument ''position'' must be a number greater than 0';
END IF;
IF $5 < 0 THEN
RAISE EXCEPTION 'argument ''occurrence'' must be a positive number';
END IF;
-- Set the modifiers
IF $5 = 0 THEN
modifiers := oracle.translate_oracle_modifiers($6, true);
ELSE
modifiers := oracle.translate_oracle_modifiers($6, false);
END IF;
-- Check if the occurrence queried exceeds the number of occurrences
IF $5 > 1 THEN
v_nummatch := (SELECT count(*) FROM regexp_matches(substr($1, $4), $2, $6||'g'));
IF $5 > v_nummatch THEN
RETURN $1;
END IF;
-- Get the position of the occurrence we are looking for
v_pos := oracle.regexp_instr($1, $2, $4, $5, 0, $6, 1);
IF v_pos = 0 THEN
RETURN $1;
END IF;
END IF;
-- Get the substring before this position we will need to restore it
v_before := substr($1, 1, v_pos - 1);
-- Replace occurrence(s)
v_replaced_str := v_before || pg_catalog.regexp_replace(substr($1, v_pos), $2, $3, modifiers);
RETURN v_replaced_str;
END;
$$
LANGUAGE plpgsql;
AS 'MODULE_PATHNAME','orafce_textregexreplace_extended'
LANGUAGE 'c' IMMUTABLE;

CREATE OR REPLACE FUNCTION oracle.regexp_replace(text, text, text, text)
RETURNS text
AS 'MODULE_PATHNAME','orafce_textregexreplace'
LANGUAGE 'c' IMMUTABLE;

----
-- Add LEAST/GREATEST declaration to return NULL on NULL input.
Expand Down
Loading

0 comments on commit 12b4403

Please sign in to comment.