SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


update statement with isnull and nullif functions.


update statement with isnull and nullif functions.

Author
Message
Maina-456685
Maina-456685
Valued Member
Valued Member (63 reputation)Valued Member (63 reputation)Valued Member (63 reputation)Valued Member (63 reputation)Valued Member (63 reputation)Valued Member (63 reputation)Valued Member (63 reputation)Valued Member (63 reputation)

Group: General Forum Members
Points: 63 Visits: 281
:-P1.SP_ Template
@Code char(30),
@Path varchar (50),
@PathReadOnlyInd int

The SP must update table MyTable
If any one of the parameters @Path or @PathReadOnlyInd are null or blank the value currently in the table must remain unchanged. Use one update statement with isnull and nullif functions.

CREATE PROCEDURE dbo.SP_Template
@Code char(30),
@Path varchar(100) = null,
@PathReadOnly int = null

AS

BEGIN
UPDATE dbo.Mytable
SET
Path = isnull(nullif(@Path,''),'')
PathReadOnly = isnull(nullif(@PathReadOnly,''),'')
FROM dbo. Mytable
WHERE Code = @Code
END

But this will overwrite the current values with blanks.
shadow_2
shadow_2
SSC Veteran
SSC Veteran (259 reputation)SSC Veteran (259 reputation)SSC Veteran (259 reputation)SSC Veteran (259 reputation)SSC Veteran (259 reputation)SSC Veteran (259 reputation)SSC Veteran (259 reputation)SSC Veteran (259 reputation)

Group: General Forum Members
Points: 259 Visits: 349
Hi,

I believe this should work, but it is untested because you provided no sample data. Smile


CREATE PROCEDURE dbo.SP_Template
@Code char(30),
@Path varchar(100) = null,
@PathReadOnly int = null

AS
BEGIN

--set @path = null if it is blank
IF LEN(LTRIM(RTRIM(ISNULL(@path,''))) = 0
SET @path = null

UPDATE m
SET
Path = ISNULL(@Path,m.path),
PathReadOnly = ISNULL(@PathReadOnly,m.PathReadOnly)
FROM dbo.Mytable as m
WHERE Code = @Code

END



The isnull() will return the value from your table if @path/@PathReadOnly is null.

Steffen.
Eugene Elutin
Eugene Elutin
SSC-Insane
SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)

Group: General Forum Members
Points: 23378 Visits: 5478
As being minimalist, the following single line will also work to set your param to null if it is a blank (or spaces) without any trims and checks for length (it would also work if your @path param would be of CHAR datatype):


SET @path = NULLIF(@path,'')



Actually, you don't need even that, just use:


UPDATE m
SET
Path = ISNULL(@Path,NULLIF(m.path,'')), -- don't update when no path supplied
PathReadOnly = ISNULL(@PathReadOnly,m.PathReadOnly)
FROM dbo.Mytable as m
WHERE Code = @Code



_____________________________________________
"The only true wisdom is in knowing you know nothing"
"O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
(So many miracle inventions provided by MS to us...)

How to post your question to get the best and quick help
shadow_2
shadow_2
SSC Veteran
SSC Veteran (259 reputation)SSC Veteran (259 reputation)SSC Veteran (259 reputation)SSC Veteran (259 reputation)SSC Veteran (259 reputation)SSC Veteran (259 reputation)SSC Veteran (259 reputation)SSC Veteran (259 reputation)

Group: General Forum Members
Points: 259 Visits: 349
Shouldn't the NULLIF be around the @Path variable?


UPDATE m
SET
Path = ISNULL(NULLIF(@Path,''),m.path), -- don't update when no path supplied
PathReadOnly = ISNULL(@PathReadOnly,m.PathReadOnly)
FROM dbo.Mytable as m
WHERE Code = @Code



I did never use NULLIF before, but it looks really useful. Wink

Steffen.
Eugene Elutin
Eugene Elutin
SSC-Insane
SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)

Group: General Forum Members
Points: 23378 Visits: 5478
Just another small advice:

Don't use stored proc input parameters directly in the WHERE clause of query, copy them into the local variables first and use the local variables instead.
It will prevent performance problems due to parameter sniffing.

_____________________________________________
"The only true wisdom is in knowing you know nothing"
"O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
(So many miracle inventions provided by MS to us...)

How to post your question to get the best and quick help
Kingston Dhasian
Kingston Dhasian
SSCrazy Eights
SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)

Group: General Forum Members
Points: 9014 Visits: 5320
You can also use a CASE statement for the same

UPDATE   dbo.Mytable
SET @Path = COALESCE( @Path, '' ),
@PathReadOnly = COALESCE( @PathReadOnly, '' ) ,
Path = CASE WHEN @Path = '' THEN Path ELSE @Path END,
PathReadOnly = CASE WHEN @PathReadOnly = '' THEN PathReadOnly ELSE @PathReadOnly END
WHERE Code = @Code




Looks longer but easy to read and understand


Kingston Dhasian

How to post data/code on a forum to get the best help - Jeff Moden
http://www.sqlservercentral.com/articles/Best+Practices/61537/
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum







































































































































































SQLServerCentral


Search