Thread: Null not equal to '' (empty)
Why is ''(empty) not equal to null? Its a major headache when porting from other RDBMS like Oracle. Anyone knows any easy workarounds? i.e. if you use: create table tbl ( c1 varchar(5)); insert into tbl values (''); select * from tbl where c1 is null; will return zero rows. Also try this: select TO_DATE('','DD-MM-YY'); and this TO_DATE('','DD-Mon-YY'); ;-) -Ajit (ajit_aranha@rocketmail.com) __________________________________________________ Do you Yahoo!? New DSL Internet Access from SBC & Yahoo! http://sbc.yahoo.com
This is because '' is not equal to NULL '' Means a empty string NULL means a empty set So this: SELECT * FROM tbl WHERE c1 IS NULL; is totally different then: SELECT * FROM tbl WHERE c1=''; Ries -----Oorspronkelijk bericht----- Van: pgsql-sql-owner@postgresql.org [mailto:pgsql-sql-owner@postgresql.org]Namens Ajit Aranha Verzonden: vrijdag 20 september 2002 8:09 Aan: pgsql-sql@postgresql.org Onderwerp: [SQL] Null not equal to '' (empty) Why is ''(empty) not equal to null? Its a major headache when porting from other RDBMS like Oracle. Anyone knows any easy workarounds? i.e. if you use: create table tbl ( c1 varchar(5)); insert into tbl values (''); select * from tbl where c1 is null; will return zero rows. Also try this: select TO_DATE('','DD-MM-YY'); and this TO_DATE('','DD-Mon-YY'); ;-) -Ajit (ajit_aranha@rocketmail.com) __________________________________________________ Do you Yahoo!? New DSL Internet Access from SBC & Yahoo! http://sbc.yahoo.com ---------------------------(end of broadcast)--------------------------- TIP 4: Don't 'kill -9' the postmaster
On Friday 20 Sep 2002 7:09 am, Ajit Aranha wrote: > Why is ''(empty) not equal to null? Its a major headache when porting > from other RDBMS like Oracle. Anyone knows any easy workarounds? By definition it is different - null means "not known" or "no value" not empty string. Do you think it should be zero for numbers? > i.e. if you use: create table tbl ( > c1 varchar(5)); > insert into tbl values (''); > select * from tbl where c1 is null; will return > zero rows. Yep - that's the way it should be. If you want empty-strings, ask for them. If you don't want to allow null values in a column define it as NOT NULL. - Richard Huxton
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