From: | Sam Stearns <sam(dot)stearns(at)dat(dot)com> |
---|---|
To: | William Alves Da Silva <william_silva(at)unochapeco(dot)edu(dot)br> |
Cc: | pgsql-sql <pgsql-sql(at)lists(dot)postgresql(dot)org> |
Subject: | Re: Postgres View DDL |
Date: | 2024-10-16 23:07:29 |
Message-ID: | CAN6TVj=oFtZxz9D-TqWR5e=4oqxO2=fTmqA13vWh0mMpxnWDFw@mail.gmail.com |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-sql |
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)),
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(at)unochapeco(dot)edu(dot)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(dot)stearns(at)dat(dot)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.
>
> Sam
>
> On Wed, Oct 16, 2024 at 2:33 PM Sam Stearns <sam(dot)stearns(at)dat(dot)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:
>>
>>
>> https://www.postgresql.org/docs/current/functions-conditional.html#FUNCTIONS-COALESCE-NVL-IFNULL
>> https://www.postgresql.org/docs/current/typeconv-union-case.html
>>
>> 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
>>
>> --
>>
>> *Samuel Stearns*
>> Lead Database Administrator
>> *c:* 971 762 6879 | *o:* 503 672 5115 | DAT.com
>> [image: DAT]
>> <https://www.dat.com/?utm_medium=email&utm_source=DAT_email_signature_link>
>>
>
>
> --
>
> *Samuel Stearns*
> Lead Database Administrator
> *c:* 971 762 6879 | *o:* 503 672 5115 | DAT.com
> [image: DAT]
> <https://www.dat.com/?utm_medium=email&utm_source=DAT_email_signature_link>
>
>
>
--
*Samuel Stearns*
Lead Database Administrator
*c:* 971 762 6879 | *o:* 503 672 5115 | DAT.com
[image: DAT]
<https://www.dat.com/?utm_medium=email&utm_source=DAT_email_signature_link>
From | Date | Subject | |
---|---|---|---|
Next Message | szy | 2024-11-25 15:46:28 | Inconsistent results for division and multiplication operations |
Previous Message | William Alves Da Silva | 2024-10-16 22:04:17 | Re: Postgres View DDL |