Thread: Postgres View DDL
Howdy,
I have an Oracle view that's been converted for Postgres. This block of code in the Oracle view DDL:
TO_NUMBER (NVL (REGEXP_REPLACE (broker_mc, '[^0-9]+', ''), 0)),
TO_NUMBER (NVL (REGEXP_REPLACE (carrier_mc, '[^0-9]+', ''), 0)),
TO_NUMBER (NVL (REGEXP_REPLACE (freight_forwarder_mc, '[^0-9]+', ''), 0)),
TO_NUMBER (NVL (REGEXP_REPLACE (carrier_mc, '[^0-9]+', ''), 0)),
TO_NUMBER (NVL (REGEXP_REPLACE (freight_forwarder_mc, '[^0-9]+', ''), 0)),
has been converted for Postgres as:
(coalesce(REGEXP_REPLACE(broker_mc, '[^0-9]+', '', 'g'), 0))::numeric ,
(coalesce(REGEXP_REPLACE(carrier_mc, '[^0-9]+', '', 'g'), 0))::numeric ,
(coalesce(REGEXP_REPLACE(freight_forwarder_mc, '[^0-9]+', '', 'g'), 0))::numeric ,
(coalesce(REGEXP_REPLACE(carrier_mc, '[^0-9]+', '', 'g'), 0))::numeric ,
(coalesce(REGEXP_REPLACE(freight_forwarder_mc, '[^0-9]+', '', 'g'), 0))::numeric ,
which is throwing the following error:
ERROR: COALESCE types text and integer cannot be matched
LINE 43: ...ce(REGEXP_REPLACE(broker_mc, '[^0-9]+', '', 'g'), 0))::numer...
^
--
LINE 43: ...ce(REGEXP_REPLACE(broker_mc, '[^0-9]+', '', 'g'), 0))::numer...
^
I have been looking through:
but I'm not seeing a way to resolve it. Would anyone be able to advise how to correct this for Postgres, please?
Thanks,
Sam
Tried changing to this:
(coalesce(REGEXP_REPLACE(broker_mc::numeric, '[^0-9]+', '', 'g'), 0)),
(coalesce(REGEXP_REPLACE(carrier_mc::numeric, '[^0-9]+', '', 'g'), 0)),
(coalesce(REGEXP_REPLACE(freight_forwarder_mc::numeric, '[^0-9]+', '', 'g'), 0)),
(coalesce(REGEXP_REPLACE(carrier_mc::numeric, '[^0-9]+', '', 'g'), 0)),
(coalesce(REGEXP_REPLACE(freight_forwarder_mc::numeric, '[^0-9]+', '', 'g'), 0)),
but that throws this error:
ERROR: function regexp_replace(numeric, unknown, unknown, unknown) does not exist
LINE 46: (coalesce(REGEXP_REPLACE(broker_mc::numeric, '[^0-9]+', ...
^
HINT: No function matches the given name and argument types. You might need to add explicit type casts.
LINE 46: (coalesce(REGEXP_REPLACE(broker_mc::numeric, '[^0-9]+', ...
^
HINT: No function matches the given name and argument types. You might need to add explicit type casts.
Sam
On Wed, Oct 16, 2024 at 2:33 PM Sam Stearns <sam.stearns@dat.com> wrote:
Howdy,I have an Oracle view that's been converted for Postgres. This block of code in the Oracle view DDL:TO_NUMBER (NVL (REGEXP_REPLACE (broker_mc, '[^0-9]+', ''), 0)),
TO_NUMBER (NVL (REGEXP_REPLACE (carrier_mc, '[^0-9]+', ''), 0)),
TO_NUMBER (NVL (REGEXP_REPLACE (freight_forwarder_mc, '[^0-9]+', ''), 0)),has been converted for Postgres as:(coalesce(REGEXP_REPLACE(broker_mc, '[^0-9]+', '', 'g'), 0))::numeric ,
(coalesce(REGEXP_REPLACE(carrier_mc, '[^0-9]+', '', 'g'), 0))::numeric ,
(coalesce(REGEXP_REPLACE(freight_forwarder_mc, '[^0-9]+', '', 'g'), 0))::numeric ,which is throwing the following error:ERROR: COALESCE types text and integer cannot be matched
LINE 43: ...ce(REGEXP_REPLACE(broker_mc, '[^0-9]+', '', 'g'), 0))::numer...
^I have been looking through:but I'm not seeing a way to resolve it. Would anyone be able to advise how to correct this for Postgres, please?Thanks,Sam--
On Wednesday, October 16, 2024, Sam Stearns <sam.stearns@dat.com> wrote:
Tried changing to this:(coalesce(REGEXP_REPLACE(broker_mc::numeric, '[^0-9]+', '', 'g'), 0)),
Both parts of the coalesce need to be integer. Therefore:
regexp_replace(…)::integer
In short, the output of the text manipulation better be something that can be cast to integer if you want coalesce to produce an integer.
David J.
Hello Sam.
I think you want this:
SELECT COALESCE(regexp_replace('abc12345'::TEXT, '[^0-9]+', '', 'g')::NUMERIC, 0);
The coalesce need the same type from origin field, or you cast the result from regex to interger/numeric etc, or you use cast ‘0’ instead of 0;
Regards,
William Alves.
On 16 Oct 2024, at 18:42, Sam Stearns <sam.stearns@dat.com> wrote:Tried changing to this:(coalesce(REGEXP_REPLACE(broker_mc::numeric, '[^0-9]+', '', 'g'), 0)),
(coalesce(REGEXP_REPLACE(carrier_mc::numeric, '[^0-9]+', '', 'g'), 0)),
(coalesce(REGEXP_REPLACE(freight_forwarder_mc::numeric, '[^0-9]+', '', 'g'), 0)),but that throws this error:ERROR: function regexp_replace(numeric, unknown, unknown, unknown) does not exist
LINE 46: (coalesce(REGEXP_REPLACE(broker_mc::numeric, '[^0-9]+', ...
^
HINT: No function matches the given name and argument types. You might need to add explicit type casts.SamOn Wed, Oct 16, 2024 at 2:33 PM Sam Stearns <sam.stearns@dat.com> wrote:Howdy,I have an Oracle view that's been converted for Postgres. This block of code in the Oracle view DDL:TO_NUMBER (NVL (REGEXP_REPLACE (broker_mc, '[^0-9]+', ''), 0)),
TO_NUMBER (NVL (REGEXP_REPLACE (carrier_mc, '[^0-9]+', ''), 0)),
TO_NUMBER (NVL (REGEXP_REPLACE (freight_forwarder_mc, '[^0-9]+', ''), 0)),has been converted for Postgres as:(coalesce(REGEXP_REPLACE(broker_mc, '[^0-9]+', '', 'g'), 0))::numeric ,
(coalesce(REGEXP_REPLACE(carrier_mc, '[^0-9]+', '', 'g'), 0))::numeric ,
(coalesce(REGEXP_REPLACE(freight_forwarder_mc, '[^0-9]+', '', 'g'), 0))::numeric ,which is throwing the following error:ERROR: COALESCE types text and integer cannot be matched
LINE 43: ...ce(REGEXP_REPLACE(broker_mc, '[^0-9]+', '', 'g'), 0))::numer...
^I have been looking through:but I'm not seeing a way to resolve it. Would anyone be able to advise how to correct this for Postgres, please?Thanks,Sam----
Just adopting William's advice and changing to this:
(coalesce(REGEXP_REPLACE(broker_mc::text, '[^0-9]+', '', 'g')::numeric, 0)),
(coalesce(REGEXP_REPLACE(carrier_mc::text, '[^0-9]+', '', 'g')::numeric, 0)),
(coalesce(REGEXP_REPLACE(freight_forwarder_mc::text, '[^0-9]+', '', 'g')::numeric, 0)),
(coalesce(REGEXP_REPLACE(carrier_mc::text, '[^0-9]+', '', 'g')::numeric, 0)),
(coalesce(REGEXP_REPLACE(freight_forwarder_mc::text, '[^0-9]+', '', 'g')::numeric, 0)),
has resolved the problem. Thank you, William and David! Learning a lot here. Appreciate all the help.
Sam
On Wed, Oct 16, 2024 at 3:04 PM William Alves Da Silva <william_silva@unochapeco.edu.br> wrote:
Hello Sam.I think you want this:SELECT COALESCE(regexp_replace('abc12345'::TEXT, '[^0-9]+', '', 'g')::NUMERIC, 0);
The coalesce need the same type from origin field, or you cast the result from regex to interger/numeric etc, or you use cast ‘0’ instead of 0;Regards,William Alves.On 16 Oct 2024, at 18:42, Sam Stearns <sam.stearns@dat.com> wrote:Tried changing to this:(coalesce(REGEXP_REPLACE(broker_mc::numeric, '[^0-9]+', '', 'g'), 0)),
(coalesce(REGEXP_REPLACE(carrier_mc::numeric, '[^0-9]+', '', 'g'), 0)),
(coalesce(REGEXP_REPLACE(freight_forwarder_mc::numeric, '[^0-9]+', '', 'g'), 0)),but that throws this error:ERROR: function regexp_replace(numeric, unknown, unknown, unknown) does not exist
LINE 46: (coalesce(REGEXP_REPLACE(broker_mc::numeric, '[^0-9]+', ...
^
HINT: No function matches the given name and argument types. You might need to add explicit type casts.SamOn Wed, Oct 16, 2024 at 2:33 PM Sam Stearns <sam.stearns@dat.com> wrote:Howdy,I have an Oracle view that's been converted for Postgres. This block of code in the Oracle view DDL:TO_NUMBER (NVL (REGEXP_REPLACE (broker_mc, '[^0-9]+', ''), 0)),
TO_NUMBER (NVL (REGEXP_REPLACE (carrier_mc, '[^0-9]+', ''), 0)),
TO_NUMBER (NVL (REGEXP_REPLACE (freight_forwarder_mc, '[^0-9]+', ''), 0)),has been converted for Postgres as:(coalesce(REGEXP_REPLACE(broker_mc, '[^0-9]+', '', 'g'), 0))::numeric ,
(coalesce(REGEXP_REPLACE(carrier_mc, '[^0-9]+', '', 'g'), 0))::numeric ,
(coalesce(REGEXP_REPLACE(freight_forwarder_mc, '[^0-9]+', '', 'g'), 0))::numeric ,which is throwing the following error:ERROR: COALESCE types text and integer cannot be matched
LINE 43: ...ce(REGEXP_REPLACE(broker_mc, '[^0-9]+', '', 'g'), 0))::numer...
^I have been looking through:but I'm not seeing a way to resolve it. Would anyone be able to advise how to correct this for Postgres, please?Thanks,Sam----