Thread: NULLIF problem

NULLIF problem

From
"Gera Mel Handumon"
Date:
HELLO,<br /><br />I encounter an error if i use NULLIF with timestamp with time zone.<br />eq.
dbtime=nullif(mytime,'')<br/><br />i want to null the value of field DBTIME if the variable mytime=" "<br /><br
/>DBTIME="timestamp with time zone" datatype <br /><br />error: column DBTIME is of type timestamp with time zone but
expressionis of type text.<br /><br />What should i do?<br /><br />Thanks in advance...<br clear="all" /><br />-- <br
/>GeraMel E. Handumon<br />Application Programmer <br />PaySoft Solutions, Inc.<br
/>-----------------------------------------------------------------<br/>"Share your knowledge. It's a way to achieve
immortality"- Dalai Lama  

Re: NULLIF problem

From
Michael Glaesemann
Date:
On Nov 27, 2007, at 21:04 , Gera Mel Handumon wrote:

> I encounter an error if i use NULLIF with timestamp with time zone.
> eq. dbtime=nullif(mytime,'')
>
> i want to null the value of field DBTIME if the variable mytime=" "
>
> DBTIME ="timestamp with time zone" datatype
>
> error: column DBTIME is of type timestamp with time zone but  
> expression is of type text.

I believe the reason is that '' is not a valid timestamp value: think  
of it this way:

IF mytime = '' THEN  mytime := NULL;
END IF;

The first thing it needs to do is compare the mytime value with ''.  
As '' is not a valid timestamp value, it may be casing mytime to  
text. You'll run into problems if you're assigning a text value to a  
timestamp field (which happens after the initial comparison--and the  
cast--are done.)

I think you may need to handle this is you middleware, or handle the  
IF THEN explicitly in a function. Maybe CASE would work:

CASE WHEN mytime = '' THEN NULL     ELSE CAST(mytime AS TIMESTAMP)    END

Michael Glaesemann
grzm seespotcode net




Re: NULLIF problem

From
Erik Jones
Date:
On Nov 27, 2007, at 8:47 PM, Michael Glaesemann wrote:

>
> On Nov 27, 2007, at 21:04 , Gera Mel Handumon wrote:
>
>> I encounter an error if i use NULLIF with timestamp with time zone.
>> eq. dbtime=nullif(mytime,'')
>>
>> i want to null the value of field DBTIME if the variable mytime=" "
>>
>> DBTIME ="timestamp with time zone" datatype
>>
>> error: column DBTIME is of type timestamp with time zone but
>> expression is of type text.
>
> I believe the reason is that '' is not a valid timestamp value:
> think of it this way:
>
> IF mytime = '' THEN
>   mytime := NULL;
> END IF;
>
> The first thing it needs to do is compare the mytime value with ''.
> As '' is not a valid timestamp value, it may be casing mytime to
> text. You'll run into problems if you're assigning a text value to
> a timestamp field (which happens after the initial comparison--and
> the cast--are done.)
>
> I think you may need to handle this is you middleware, or handle
> the IF THEN explicitly in a function. Maybe CASE would work:
>
> CASE WHEN mytime = '' THEN NULL
>      ELSE CAST(mytime AS TIMESTAMP)
>     END


Why not just:

UPDATE table
SET mytime=NULL
WHERE mytime='';

Erik Jones

Software Developer | Emma®
erik@myemma.com
800.595.4401 or 615.292.5888
615.292.0777 (fax)

Emma helps organizations everywhere communicate & market in style.
Visit us online at http://www.myemma.com




Re: NULLIF problem

From
"Gera Mel Handumon"
Date:
Thanks!<br /><br /><div class="gmail_quote">On Nov 28, 2007 10:47 AM, Michael Glaesemann <<a
href="mailto:grzm@seespotcode.net">grzm@seespotcode.net</a>>wrote:<br /><blockquote class="gmail_quote"
style="border-left:1px solid rgb(204, 204, 204); margin: 0pt 0pt 0pt 0.8ex; padding-left: 1ex;"><div class="Ih2E3d"><br
/>OnNov 27, 2007, at 21:04 , Gera Mel Handumon wrote:<br /><br />> I encounter an error if i use NULLIF with
timestampwith time zone.<br />> eq. dbtime=nullif(mytime,'')<br />><br />> i want to null the value of field
DBTIMEif the variable mytime=" " <br />><br />> DBTIME ="timestamp with time zone" datatype<br />><br />>
error:column DBTIME is of type timestamp with time zone but<br />> expression is of type text.<br /><br /></div>I
believethe reason is that '' is not a valid timestamp value: think <br />of it this way:<br /><br />IF mytime = ''
THEN<br/>   mytime := NULL;<br />END IF;<br /><br />The first thing it needs to do is compare the mytime value with
''.<br/>As '' is not a valid timestamp value, it may be casing mytime to <br />text. You'll run into problems if you're
assigninga text value to a<br />timestamp field (which happens after the initial comparison--and the<br />cast--are
done.)<br/><br />I think you may need to handle this is you middleware, or handle the <br />IF THEN explicitly in a
function.Maybe CASE would work:<br /><br />CASE WHEN mytime = '' THEN NULL<br />      ELSE CAST(mytime AS TIMESTAMP)<br
/>    END<br /><font color="#888888"><br />Michael Glaesemann<br />grzm seespotcode net <br /><br /><br
/></font></blockquote></div><br/><br clear="all" /><br />-- <br />Gera Mel E. Handumon<br />Application Programmer<br
/>PaySoftSolutions, Inc.<br />-----------------------------------------------------------------<br />"Share your
knowledge.It's a way to achieve immortality" - Dalai Lama  

Re: NULLIF problem

From
Michael Glaesemann
Date:
On Nov 28, 2007, at 14:00 , Erik Jones wrote:

> Why not just:
>
> UPDATE table
> SET mytime=NULL
> WHERE mytime='';

If mytime is a timestamp field, it won't have any values ''. I  
believe the OP is updating mytime to a client-supplied value which is  
passing '' when it probably means NULL.

Michael Glaesemann
grzm seespotcode net