Re: Null not equal to '' (empty) - Mailing list pgsql-sql

From Josh Berkus
Subject Re: Null not equal to '' (empty)
Date
Msg-id web-1731902@davinci.ethosmedia.com
Whole thread Raw
In response to Null not equal to '' (empty)  (Ajit Aranha <ajit_aranha@rocketmail.com>)
List pgsql-sql
Ajit,

>  Why is ''(empty) not equal to null? Its a major headache when
> porting
> from other RDBMS like Oracle. 

'' is not equal to NULL because that is the ANSI SQL92 and SQL99
international specification.   The fact that other databases fail to
follow the specification (and '' = NULL is *not* standard Oracle 8
behavior, either, so I don't know what you are porting from ... MS
Access?) is not our concern.   

NULL is not equal to *anything*, including itself.  Nor is it greater
or less than anything.  In fact, any operation involving NULL should
result in NULL.  This is the SQL spec, becuase NULL represents
"unknown" and thus cannot be evaluated.

For my intranet applications, I wrote a set of functions called
"is_empty(data)" since my web programmer is rather liberal in
substituting NULL for '' or for '0' or whatever.  They go like this:

CREATE FUNCTION is_empty( VARCHAR ) RETURNS BOOLEAN AS '
SELECT $1 IS NULL OR BTRIM($1) = '';
' LANGUAGE 'sql' WITH (ISCACHABLE);

CREATE FUNCTION is_empty( NUMERIC ) RETURNS BOOLEAN AS '
SELECT $1 IS NULL OR $1 = 0::NUMERIC;
' LANGUAGE 'sql' WITH (ISCACHABLE);

etc.

This will give you an all-purpose "empty value" detector.

-Josh Berkus
Aglio Database Solutions
San Francisco


pgsql-sql by date:

Previous
From: Stephan Szabo
Date:
Subject: Re: Dublicates pairs in a table.
Next
From: Richard Huxton
Date:
Subject: Re: Dublicates pairs in a table.