Execute Dynamic SQL commands in SQL Server

In some applications having hard-coded SQL statements is not appealing, because of the dynamic nature of the queries being issued against the database server. Because of this sometimes there is a need to dynamically create a SQL statement on the fly and then run that command. This can be done quite simply from the application perspective where the statement is built on the fly whether you are using ASP.NET , ColdFusion or any other programming language. But how do you do this from within a SQL Server stored procedure? SQL Server offers a few ways of running a dynamically built SQL statement. These ways are: Writing a query with parameters Using EXEC Using sp_executesql Writing a query with parameters This first approach is pretty straightforward if you only need to pass parameters into the WHERE clause of your SQL statement. Let’s say we need to find all records from the Customers table where City = ‘London’. This can be done easily as the following example shows.

How To Use COALESCE And NULLIF To Prevent Updating Columns When A Parameter IS NULL Or A Default Value

Let's say you have a proc like this


CREATE PROC prUpdateTable
@Salesman
int = -1
AS

..........

If the user calls the proc like this exec prUpdateTable null then @Salesman will be null, if the user calls the proc like this exec prUpdateTable then the value of @Salesman will be -1. In both of this cases you don't want to change the value of the column. What can you do?
You can use a combination of NULLIF and COALESCE to handle this. Your update statement would look like this




UPDATE table
SET
Column = COALESCE(NULLIF(@variable,-1),Column)



Here is some code to demonstrate that




CREATE TABLE #foo (id int,salesman int)
INSERT #foo VALUES(1,1)
INSERT #foo VALUES(2,1)
INSERT #foo VALUES(3,1)
INSERT #foo VALUES(4,1)



SELECT * FROM #foo
-------------
1 1
2 1
3 1
4 1

DECLARE @salesman int
SELECT
@salesman = 5

--Column value will change to 5
UPDATE #foo
SET salesman = COALESCE(NULLIF(@salesman,-1),salesman)
WHERE ID =1

--Column value won't change
SELECT @salesman = -1
UPDATE #foo
SET salesman = COALESCE(NULLIF(@salesman,-1),salesman)
WHERE ID =2

--Column value won't change
SELECT @salesman = NULL
UPDATE #foo
SET salesman = COALESCE(NULLIF(@salesman,-1),salesman)
WHERE ID =3

--Column value will change to 3
SELECT @salesman = 3
UPDATE #foo
SET salesman = COALESCE(NULLIF(@salesman,-1),salesman)
WHERE ID =4

--And here is the output, as you can see when @salesman was -1 or NULL the table did not get updated
SELECT * FROM #foo
-------------
1 5
2 1
3 1
4 3

DROP TABLE #foo





As you can see only the first and the last update statement changed the value of the salesman column
Of course you would never do this if you were to update only one column, you would skip the update instead. If you have to update multiple columns then this is something you can use instead of writing a bunch of dynamic SQL or nested IF statements.

Comments

Popular posts from this blog

Check If Temporary Table Exists

Multiple NULL values in a Unique index in SQL

Row To Column