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.

Setting the execution order of Triggers in SQL Server

Using sp_Settriggerorder stored procedure, we can define the execution order of the trigger. Here is the syntax for SQL Server 2005, taken from BOL. For complete explanation of syntax, please look at BOL.

sp_settriggerorder [ @triggername = ] ‘[ triggerschema. ] triggername’
, [ @order = ] ‘value’
, [ @stmttype = ] ’statement_type’
[ , [ @namespace = ] { ‘DATABASE’ | ‘SERVER’ | NULL } ]

We are interested in the second parameter: “order”. It can take three values which means that it can take into account up-to three triggers.

  1. First – Trigger is fired first
  2. Last - Trigger is fired last
  3. None – Trigger is fired in random order.

The same procedure is available in SQLServer 2000 also but without namespace parameter because it does not support DDL triggers. Since SQL Server 2005, supports DDL trigger, namespace parameter defines the scope of the DDL trigger whether at Database level or at Server level. If value is NULL, trigger is a DML trigger.

We will use the same example as shown in yesterday’s blog. Connect to database using Management Studio. Create following table..

CREATE TABLE TEST
(
COL1 INT IDENTITY (1,1),
COL2 INT,
COL3 INT,
COL4 DATETIME
)
GO

Now we will create two DML triggers on the table.

CREATE TRIGGER dbo.TRI_TEST_2 ON dbo.TEST
FOR INSERT
AS
DECLARE @ID INT
SELECT @ID = COL1 FROM INSERTED

UPDATE dbo.TEST
SET COL3 = 5 + COL2
WHERE COL1 = @ID
GO

CREATE TRIGGER dbo.TRI_TEST_1 ON dbo.TEST
FOR INSERT
AS
DECLARE @ID INT
SELECT @ID = COL1 FROM INSERTED

UPDATE dbo.TEST
SET COL2 = 5 + @ID
WHERE COL1 = @ID
GO

Now let us insert the record in the table and examine the result.

INSERT INTO TEST(COL4) VALUES(GETDATE());

Following is the result.

SELECT * FROM TEST;

COL1 COL2 COL3 COL4
———– ———– ———– ———————–
1 6 NULL 2008-02-27 23:28:08.500

It is apparent from the result that TRI_TEST_2 got executed first at which point value of COL2 was null and as a end result, COL3 contains null value.

Let us now define the trigger order so that TRI_TEST_1 executes first and TRI_TEST_2 executes after TRI_TEST_1.

sp_Settriggerorder ‘TRI_TEST_1′,’FIRST’,'INSERT’
GO
sp_Settriggerorder ‘TRI_TEST_2′,’LAST’,'INSERT’
GO

After executing above mentioned command, insert new record and check the result. We are displaying both the records for comparison.

COL1 COL2 COL3 COL4
———– ———– ———– ———————–
1 6 NULL 2008-02-27 23:37:03.640
2 7 12 2008-02-27 23:45:25.357

With the pre-defined execution order of the trigger, all the columns are populated correctly. Similarly we can set the firing order for the DDL triggers as well.

Restrictions:
• For a single table, we can define only one first and last trigger for each statement.
• If trigger is modified using ALTER TRIGGER statement, priority of the trigger is set to None so it is very important to re-execute the sp_settriggerorder stored procedure to reset the correct execution order.
• If ‘FIRST’ or ‘LAST’ trigger already exists for the statement Type, reassigining new trigger to be the ‘FIRST’ one will result into an error.

How do we know whether any ordering is defined for the trigger or not? We can use objectproperty() function to retreive this information. Here is the query and the result.

SELECT OBJECT_NAME(PARENT_OBJ) TABLE_NAME,
NAME AS TRIGGER_NAME,
CASE OBJECTPROPERTY(ID, ‘ExecIsFirstInsertTrigger’)
WHEN 0 THEN ‘YES’
ELSE ‘NO’
END AS First
FROM SYSOBJECTS
WHERE XTYPE = ‘TR’
GO

TABLE_NAME TRIGGER_NAME First
———- ———— —–
TEST TRI_TEST_2 YES
TEST TRI_TEST_1 NO

Similarly we can check for ExecIsLastInsertTrigger property to see whether last trigger is defined for insert statement or not.

Comments

Popular posts from this blog

Check If Temporary Table Exists

Multiple NULL values in a Unique index in SQL

Row To Column