Thread: coalesce and nvl question

coalesce and nvl question

From
Simon Windsor
Date:
Hi

Is there a standard postgres method of replacing empty strings.

In Oracle, nvl handles nulls and empty strings, as does ifnull() in
MySQL, but with postgres coalesce only handles null strings.

If, not is the best solution to create a plpgsql function, ie

CREATE FUNCTION isEmpty (character varying, character varying) RETURNS
character varying
    AS '
declare
    fnRetTrue  alias for $1;
    fnRetFalse alias for $2;
begin
    if fnRetTrue = '' or fnRetTrue is not null then
        return fnRetTrue;
    else
        return fnRetFalse;
    end if;
end;
'
    LANGUAGE plpgsql;

Thanks

Simon

--
Simon Windsor
Email: simon.windsor@cornfield.org.uk
Tel: 01454 617689
Mob: 07960 321599


--
This message has been scanned for viruses and
dangerous content by MailScanner, and is
believed to be clean.
Mailscanner thanks transtec Computers for their support.


Re: coalesce and nvl question

From
Mike Mascari
Date:
Simon Windsor wrote:
> Hi
>
> Is there a standard postgres method of replacing empty strings.
>
> In Oracle, nvl handles nulls and empty strings, as does ifnull() in
> MySQL, but with postgres coalesce only handles null strings.
>
> If, not is the best solution to create a plpgsql function, ie
>
> CREATE FUNCTION isEmpty (character varying, character varying) RETURNS
> character varying

This all depends upon what you mean by handle. Do you want to treat
empty strings as NULL or NULL as empty strings? As you said, you can
treat NULL as empty strings using COALESCE:

SELECT COALESCE(x, '');

You can treat empty strings as NULL

SELECT NULLIF(x, '');

But I'd guess most on this list are wondering why you want to equate
an empty string with NULL, as they have two distinct meanings.
Oracle's treatment of empty strings as NULL is world-renowned for
being insane...

HTH

Mike Mascari



Re: coalesce and nvl question

From
Simon Windsor
Date:
Hi

I understand that null and '' are different, and MySQL and Oracle
functions are confusing, but my question was not about replacing NULL
but replacing Empty strings. These are handled in MySQL/Oracle by the
same functions that do NULL checks.

Is there a standard function in Postgres that replaces Empty strings, as
against a NULL value.

Simon



On Wed, 2004-06-23 at 18:05, Mike Mascari wrote:
> Simon Windsor wrote:
> > Hi
> >
> > Is there a standard postgres method of replacing empty strings.
> >
> > In Oracle, nvl handles nulls and empty strings, as does ifnull() in
> > MySQL, but with postgres coalesce only handles null strings.
> >
> > If, not is the best solution to create a plpgsql function, ie
> >
> > CREATE FUNCTION isEmpty (character varying, character varying) RETURNS
> > character varying
>
> This all depends upon what you mean by handle. Do you want to treat
> empty strings as NULL or NULL as empty strings? As you said, you can
> treat NULL as empty strings using COALESCE:
>
> SELECT COALESCE(x, '');
>
> You can treat empty strings as NULL
>
> SELECT NULLIF(x, '');
>
> But I'd guess most on this list are wondering why you want to equate
> an empty string with NULL, as they have two distinct meanings.
> Oracle's treatment of empty strings as NULL is world-renowned for
> being insane...
>
> HTH
>
> Mike Mascari
--
Simon Windsor
Email: simon.windsor@cornfield.org.uk
Tel: 01454 617689
Mob: 07960 321599


--
This message has been scanned for viruses and
dangerous content by MailScanner, and is
believed to be clean.
Mailscanner thanks transtec Computers for their support.


Re: coalesce and nvl question

From
Doug McNaught
Date:
Simon Windsor <simon.windsor@cornfield.org.uk> writes:

> Hi
>
> I understand that null and '' are different, and MySQL and Oracle
> functions are confusing, but my question was not about replacing NULL
> but replacing Empty strings. These are handled in MySQL/Oracle by the
> same functions that do NULL checks.
>
> Is there a standard function in Postgres that replaces Empty strings, as
> against a NULL value.

I don't think so, but you could use a CASE clause for this.

-Doug

Re: coalesce and nvl question

From
Bruno Wolff III
Date:
On Wed, Jun 23, 2004 at 19:10:05 +0100,
  Simon Windsor <simon.windsor@cornfield.org.uk> wrote:
> Hi
>
> I understand that null and '' are different, and MySQL and Oracle
> functions are confusing, but my question was not about replacing NULL
> but replacing Empty strings. These are handled in MySQL/Oracle by the
> same functions that do NULL checks.
>
> Is there a standard function in Postgres that replaces Empty strings, as
> against a NULL value.

Something like the following may suit your purposes:
coallesce(nullif(inputstring,''), 'replacement value')

Re: coalesce and nvl question

From
Simon Windsor
Date:
Hi

Thanks, I should have thought of that myself!

Simon
On Wed, 2004-06-23 at 19:43, Bruno Wolff III wrote:
> On Wed, Jun 23, 2004 at 19:10:05 +0100,
>   Simon Windsor <simon.windsor@cornfield.org.uk> wrote:
> > Hi
> >
> > I understand that null and '' are different, and MySQL and Oracle
> > functions are confusing, but my question was not about replacing NULL
> > but replacing Empty strings. These are handled in MySQL/Oracle by the
> > same functions that do NULL checks.
> >
> > Is there a standard function in Postgres that replaces Empty strings, as
> > against a NULL value.
>
> Something like the following may suit your purposes:
> coallesce(nullif(inputstring,''), 'replacement value')
>
> ---------------------------(end of broadcast)---------------------------
> TIP 6: Have you searched our list archives?
>
>                http://archives.postgresql.org
--
Simon Windsor
Email: simon.windsor@cornfield.org.uk
Tel: 01454 617689
Mob: 07960 321599


--
This message has been scanned for viruses and
dangerous content by MailScanner, and is
believed to be clean.
Mailscanner thanks transtec Computers for their support.