Convert Hex to String – MSDN TSQL forum
–> Question:
How can I convert the hex code ‘0x16004D616E75623232’ to string?
An online utility provides me its equivalent: http://www.string-functions.com/hex-string.aspx
But how can I do this by TSQL, CLR would be a second thought.
–> Answer:
Didn’t thought it was so simple, actually my hex string had ‘1600’ prefixed after 0x, on removing it I’m getting the expected o/p, which is:
SELECT CONVERT(varchar(64), 0x4D616E75623232, 0)
–> Answer from Hunchback:
If you are using SS 2008 or earlier, then check function CONVERT in BOL.
SELECT CONVERT(varbinary(64), '0x16004D616E75623232', 1), CONVERT(varchar(64), 0x16004D616E75623232, 1), CONVERT(varchar(64), 0x16004D616E75623232, 2); GO
For lower versions you can use some tricks from Umachandar Jayachandran, link: http://social.msdn.microsoft.com/Forums/en-US/transactsql/thread/20e92e10-a0ab-4a53-a766-76f84bfd4e8c
Ref link
SQL Error – UPDATE statement conflicted with the FOREIGN KEY/REFERENCE constraint
Just replied on MSDN forum’s following post: http://social.msdn.microsoft.com/Forums/en-US/transactsql/thread/289c4ca5-6ab2-4ed6-b446-0300f5c7dc88
When tables are referenced by Foreign Key constraints it gets difficult to UPDATE the key columns.
An example shows this issue and how one can perform UPDATE on FK columns.
USE [tempdb] GO -- CREATE test tables CREATE TABLE dept (d_id INT PRIMARY KEY, dept VARCHAR(50)) CREATE TABLE emp (sn INT PRIMARY KEY, ename VARCHAR(50), d_fk INT CONSTRAINT fk_dept_d_fk FOREIGN KEY (d_fk) REFERENCES dept(d_id)) -- INSERT test data INSERT INTO dept SELECT 1, 'finance' UNION SELECT 2, 'hr' INSERT INTO emp SELECT 1, 'Manoj', 1 UNION SELECT 2, 'Saurabh', 2 UNION SELECT 3, 'Kanchan', 1 UNION SELECT 4, 'Pooja', 2 -- SELECT the INSERTed data SELECT * from dept
d_id dept
1 finance
2 hr -- DeptID needs to be updated to 3
SELECT * from emp
sn ename d_fk
1 Manoj 1
2 Saurabh 2 -- DeptID should also be updated here to 3
3 Kanchan 1
4 Pooja 2 -- DeptID should also be updated here to 3
-- Now lets UPDATE the FK column values UPDATE dept SET d_id=3 WHERE d_id=2
Error Message:
Msg 547, Level 16, State 0, Line 1
The UPDATE statement conflicted with the REFERENCE constraint "fk_dept_d_fk".
The conflict occurred in database "tempdb", table "dbo.emp", column 'd_fk'.
The statement has been terminated.
UPDATE emp SET d_fk=3 WHERE d_fk=2
Error Message:
Msg 547, Level 16, State 0, Line 1
The UPDATE statement conflicted with the FOREIGN KEY constraint "fk_dept_d_fk".
The conflict occurred in database "tempdb", table "dbo.dept", column 'd_id'.
The statement has been terminated.
We can disable the FK constraints by ALTER statement before the UPDATE and enable them after the UPDATE, like:
-- Disable FK Constraint ALTER TABLE emp NOCHECK CONSTRAINT fk_dept_d_fk -- Perform UPDATE UPDATE dept SET d_id=3 WHERE d_id=2 UPDATE emp SET d_fk=3 WHERE d_fk=2 -- Enable FK Constraint ALTER TABLE emp WITH CHECK CHECK CONSTRAINT fk_dept_d_fk -- Following SELECTS will show the new values in updated records: SELECT * from dept
d_id dept
1 finance
3 hr -- Updated record
SELECT * from emp
sn ename d_fk
1 Manoj 1
2 Saurabh 3 -- Updated record
3 Kanchan 1
4 Pooja 3 -- Updated record
-- Final Cleanup, DROP the tables. DROP TABLE emp DROP TABLE dept
MSDN BOL: http://msdn.microsoft.com/en-us/library/10cetyt6(v=VS.80).aspx
CROSS APPLY vs OUTER APPLY operators in SQL Server
In my [previous post] we learnt about UDFs, their types and implementations. UDFs can be used in queries at column level, table levels and on column definition while creating tables.
They can also be joined with other tables, but not by simple joins. They use special join-keyword called APPLY operator.
According to MS BOL an APPLY operator allows you to invoke a table-valued function for each row returned by an outer table expression of a query. The table-valued function acts as the right input and the outer table expression acts as the left input. The right input is evaluated for each row from the left input and the rows produced are combined for the final output. The list of columns produced by the APPLY operator is the set of columns in the left input followed by the list of columns returned by the right input.
–> There are 2 forms of APPLY operators:
1. CROSS APPLY acts as INNER JOIN, returns only rows from the outer table that produce a result set from the table-valued function.
2. OUTER APPLY acts as OUTER JOIN, returns both rows that produce a result set, and rows that do not, with NULL values in the columns produced by the table-valued function.
Lets take 2 tables: Person.Contact & Sales.SalesOrderHeader
SELECT * FROM Person.Contact WHERE ContactID = 100 SELECT * FROM Sales.SalesOrderHeader WHERE ContactID = 100
You have a UDF that returns Sales Order Details of a Particular Contact. Now you want to use that UDF to know what all Contacts have Ordered what with other details, let’s see:
–> First creating a UDF to test with JOINS & APPLY:
--// Create Multiline UserDefinedFunction [dbo].[ufn_mtv_GetContactSales]
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE FUNCTION [dbo].[ufn_mtv_GetContactSales](@ContactID int)
RETURNS @retSalesInfo TABLE (
[ContactID] INT NOT NULL,
[SalesOrderID] INT NULL,
[ProductID] INT NULL,
[Name] NVARCHAR(50) NULL,
[OrderDate] DATETIME NULL,
[DueDate] DATETIME NULL,
[ShipDate] DATETIME NULL,
[TotalDue] MONEY NULL,
[Status] TINYINT NULL,
[SalesPersonID] INT NULL)
AS
BEGIN
IF @ContactID IS NOT NULL
BEGIN
INSERT @retSalesInfo
SELECT h.[ContactID], h.[SalesOrderID], p.[ProductID], p.[Name], h.[OrderDate], h.[DueDate],
h.[ShipDate], h.[TotalDue], h.[Status], h.[SalesPersonID]
FROM Sales.SalesOrderHeader AS h
JOIN Sales.SalesOrderDetail AS d ON d.SalesOrderID = h.SalesOrderID
JOIN Production.Product AS p ON p.ProductID = d.ProductID
WHERE ContactID = @ContactID
END
-- Return the recordsets
RETURN
END
--// Test the UDF
SELECT * FROM dbo.ufn_mtv_GetContactSales(100)
–> Trying to JOIN UDF with a table, problem is you need to apply a parameter and it can’t be a column, but a value:
--// UDF with JOIN, try it out!!! SELECT * FROM Person.Contact c JOIN dbo.ufn_mtv_GetContactSales(100) f -- You will have to pass the ContactID parameter, so no use of joining. ON f.ContactID = c.ContactID
–> Testing with CROSS APPLY:
--// CROSS APPLY -- 279 records (All matched records, 1 missing out of 280) SELECT c.[ContactID], c.[FirstName], c.[LastName], c.[EmailAddress], c.[Phone], s.* FROM Person.Contact AS c CROSS APPLY ufn_mtv_GetContactSales(c.ContactID) AS s WHERE c.ContactID between 100 and 105 -- Same equivalent query without cross apply, using JOINs -- 279 records SELECT c.[ContactID], c.[FirstName], c.[LastName], c.[EmailAddress], c.[Phone], h.[ContactID], h.[SalesOrderID], p.[ProductID], p.[Name], h.[OrderDate], h.[DueDate], h.[ShipDate], h.[TotalDue], h.[Status], h.[SalesPersonID] FROM Person.Contact AS c JOIN Sales.SalesOrderHeader AS h ON c.ContactID = h.ContactID JOIN Sales.SalesOrderDetail AS d ON d.SalesOrderID = h.SalesOrderID JOIN Production.Product AS p ON p.ProductID = d.ProductID WHERE c.ContactID between 100 and 105
–> Testing with OUTER APPLY:
--// OUTER APPLY -- 280 records (All 280 records with 1 not matched) SELECT c.[ContactID], c.[FirstName], c.[LastName], c.[EmailAddress], c.[Phone], s.* FROM Person.Contact AS c OUTER APPLY ufn_mtv_GetContactSales(c.ContactID) AS s WHERE c.ContactID between 100 and 105 -- Same equivalent query without OUTER APPLY, using LEFT JOINs -- 280 records SELECT c.[ContactID], c.[FirstName], c.[LastName], c.[EmailAddress], c.[Phone], h.[ContactID], h.[SalesOrderID], p.[ProductID], p.[Name], h.[OrderDate], h.[DueDate], h.[ShipDate], h.[TotalDue], h.[Status], h.[SalesPersonID] FROM Person.Contact AS c LEFT JOIN Sales.SalesOrderHeader AS h ON c.ContactID = h.ContactID LEFT JOIN Sales.SalesOrderDetail AS d ON d.SalesOrderID = h.SalesOrderID LEFT JOIN Production.Product AS p ON p.ProductID = d.ProductID WHERE c.ContactID between 100 and 105
>> Check & Subscribe my [YouTube videos] on SQL Server.
SQL Basics – UDF | User Defined Functions – Scalar, Table Valued (TVF), MultiStatement (MTVF)
UDF or User Defined Functions are a set or batch of code where one can apply any SQL logic and return a single scalar value or a record set.
According to MS BOL UDFs are the subroutines made up of one or more Transact-SQL statements that can be used to encapsulate code for reuse. These reusable subroutines can be used as:
– In TSQL SELECT statements at column level.
– To create parametrized view or improve the functionality of in indexed view.
– To define a column and CHECK constraints while creating a table.
– To replace a stored procedures and views.
– Join complex logic with a table where a stored procedure fails.
– Faster execution like Stored procedures, reduce compliation cost by caching the execution query plans.
Apart from the benefits UDF’s has certain limitations:
– Can not modify any database objects, limited to update table variables only.
– Can not contain the new OUTPUT clause.
– Can only call extended stored procedures, no other procedures.
– Can not define TRY-CATCH block.
– Some built-in functions are not allowed here, like:GETDATE(), because GETDATE is non-deterministic as its value changes every time it is called. On the other hand DATEADD() is allowed as it is deterministic, because it will return same result when called with same argument values.
A UDF can take 0 or upto 1024 parameters and returns either a scalar value or a table record set depending on its type.
SQL Server supports mainly 3 types of UDFs:
1. Scalar function
2. Inline table-valued function
3. Multistatement table-valued function
1. Scalar function: Returns a single value of any datatype except text, ntext, image, cursor & timestamp.
-- Example: --// Create Scalar UDF [dbo].[ufn_GetContactOrders] SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE FUNCTION [dbo].[ufn_GetContactOrders](@ContactID int) RETURNS varchar(500) AS BEGIN DECLARE @Orders varchar(500) SELECT @Orders = COALESCE(@Orders + ', ', '') + CAST(SalesOrderID as varchar(10)) FROM Sales.SalesOrderHeader WHERE ContactID = @ContactID RETURN (@Orders) END --// Usage: -- Used at COLUMN level with SELECT SELECT ContactID, dbo.ufn_GetContactOrders(ContactID) FROM Person.Contact WHERE ContactID between 100 and 105 -- Output below -- Used while defining a computed column while creating a table. CREATE TABLE tempCustOrders (CustID int, Orders as (dbo.ufn_GetContactOrders(CustID))) INSERT INTO tempCustOrders (CustID) SELECT ContactID FROM Person.Contact WHERE ContactID between 100 and 105 SELECT * FROM tempCustOrders -- Output below DROP TABLE tempCustOrders
Output of both the selects above:
ContactID OrdersCSV
100 51702, 57021, 63139, 69398
101 47431, 48369, 49528, 50744, 53589, 59017, 65279, 71899
102 43874, 44519, 46989, 48013, 49130, 50274, 51807, 57113, 63162, 69495
103 43691, 44315, 45072, 45811, 46663, 47715, 48787, 49887, 51144, 55310, 61247, 67318
104 43866, 44511, 45295, 46052, 46973, 47998, 49112, 50215, 51723, 57109, 63158, 69420
105 NULL
Note: If this was a temp(#) table then the function also needs to be created in tempdb, cause the temp table belongs to tempdb. The tables in function should also have the database name prefixed, i.e. [AdventureWorks].[Sales].[SalesOrderHeader]
2. Inline table-valued function: Returns a table i.e. a record-set. The function body contains just a single TSQL statement, which results to a record-set and is returned from here.
-- Example: --// Create Inline table-valued UDF [dbo].[ufn_itv_GetContactSales] SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE FUNCTION [dbo].[ufn_itv_GetContactSales](@ContactID int) RETURNS TABLE AS RETURN ( SELECT h.[ContactID], h.[SalesOrderID], p.[ProductID], p.[Name], h.[OrderDate], h.[DueDate], h.[ShipDate], h.[TotalDue], h.[Status], h.[SalesPersonID] FROM Sales.SalesOrderHeader AS h JOIN Sales.SalesOrderDetail AS d ON d.SalesOrderID = h.SalesOrderID JOIN Production.Product AS p ON p.ProductID = d.ProductID WHERE ContactID = @ContactID ) --// Usage: SELECT * FROM ufn_itv_GetContactSales(100)
3. Multistatement table-valued function: Also returns a table (record-set) but can contain multiple TSQL statements or scripts and is defined in BEGIN END block. The final set of rows are then returned from here.
-- Example: --// Create Multistatement table-valued UDF [dbo].[ufn_mtv_GetContactSales] SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE FUNCTION [dbo].[ufn_mtv_GetContactSales](@ContactID int) RETURNS @retSalesInfo TABLE ( [ContactID] INT NOT NULL, [SalesOrderID] INT NULL, [ProductID] INT NULL, [Name] NVARCHAR(50) NULL, [OrderDate] DATETIME NULL, [DueDate] DATETIME NULL, [ShipDate] DATETIME NULL, [TotalDue] MONEY NULL, [Status] TINYINT NULL, [SalesPersonID] INT NULL) AS BEGIN IF @ContactID IS NOT NULL BEGIN INSERT @retSalesInfo SELECT h.[ContactID], h.[SalesOrderID], p.[ProductID], p.[Name], h.[OrderDate], h.[DueDate], h.[ShipDate], h.[TotalDue], h.[Status], h.[SalesPersonID] FROM Sales.SalesOrderHeader AS h JOIN Sales.SalesOrderDetail AS d ON d.SalesOrderID = h.SalesOrderID JOIN Production.Product AS p ON p.ProductID = d.ProductID WHERE ContactID = @ContactID END -- Return the recordsets RETURN END --// Usage: SELECT * FROM ufn_mtv_GetContactSales(100)
— Output:
More MSDN & MS BOL links:
http://msdn.microsoft.com/en-us/library/aa175085(SQL.80).aspx
http://msdn.microsoft.com/en-us/library/aa214363(SQL.80).aspx
http://msdn.microsoft.com/en-us/library/ms186755.aspx
http://msdn.microsoft.com/en-us/library/ms191007.aspx
http://msdn.microsoft.com/en-us/magazine/cc164062.aspx
SET ANSI_NULLS, QUOTED_IDENTIFIER, ANSI_PADDING – SQL Server
You have to create a Stored-Procedure and you need a template. You expand the Object Explorer go to Database -> Programmability -> “Stored Procedure” -> (right click) -> select “New Stored Procedure”.
A new editor opens up with lot of commented & flawless code. There you see some predefined statements.
Sometimes while working with Stored Procedures and other SQL Scripts a those few statements makes you confusing and clueless. Most of the time people remove them or just ignore them, but one should know why are they placed there. The 2 mains SET statements that are placed by default are described below with examples:
–// SET ANSI_NULLS (http://msdn.microsoft.com/en-us/library/ms188048.aspx)
Specifies ISO compliant behavior of the Equals (=) and Not Equal To (<>) comparison operators when they are used with null values.
Syntax: SET ANSI_NULLS { ON | OFF }
create table #tempTable (sn int, ename varchar(50)) insert into #tempTable select 1, 'Manoj' UNION ALL select 2, 'Pankaj' UNION ALL select 3, NULL UNION ALL select 4, 'Lokesh' UNION ALL select 5, 'Gopal' SET ANSI_NULLS ON select * from #tempTable where ename is NULL -- (1 row(s) affected)
sn ename
3 NULL
select * from #tempTable where ename = NULL -- (0 row(s) affected) select * from #tempTable where ename <> NULL -- (0 row(s) affected) SET ANSI_NULLS OFF select * from #tempTable where ename is NULL -- (1 row(s) affected) select * from #tempTable where ename = NULL -- (1 row(s) affected)
sn ename
3 NULL
select * from #tempTable where ename is not NULL -- (4 row(s) affected) select * from #tempTable where ename <> NULL -- (4 row(s) affected)
sn ename
1 Manoj
2 Pankaj
4 Lokesh
5 Gopal
drop table #tempTable
–// SET QUOTED_IDENTIFIER (http://msdn.microsoft.com/en-us/library/ms174393.aspx)
Causes SQL Server to follow the ISO rules regarding quotation mark delimiting identifiers and literal strings. Identifiers delimited by double quotation marks can be either Transact-SQL reserved keywords or can contain characters not generally allowed by the Transact-SQL syntax rules for identifiers.
When SET QUOTED_IDENTIFIER is ON, identifiers can be delimited by double quotation marks, and literals must be delimited by single quotation marks.
When SET QUOTED_IDENTIFIER is OFF, identifiers cannot be quoted and must follow all Transact-SQL rules for identifiers.
Syntax: SET QUOTED_IDENTIFIER { ON | OFF }
-- Example 1 SET QUOTED_IDENTIFIER ON create table "#tempTable" (sn int, ename varchar(50)) -- Command(s) completed successfully. SET QUOTED_IDENTIFIER OFF create table "#tempTable" (sn int, ename varchar(50)) -- Incorrect syntax near '#tempTable'. drop table #tempTable -- Example 2 SET QUOTED_IDENTIFIER ON select "'My Name is Manoj'" as Col1, "Let's play" as Col2 -- Invalid column name ''My Name is Manoj''. Invalid column name 'Let's play'. SET QUOTED_IDENTIFIER OFF select "'My Name is Manoj'" as Col1, "Let's play" as Col2 -- (1 row(s) affected)
Col1 Col2
'My Name is Manoj' Let's play
-- Example 3 SET QUOTED_IDENTIFIER ON select '''My Name is Manoj''' as Col1, 'Let''s play' as Col2 -- (1 row(s) affected)
Col1 Col2
'My Name is Manoj' Let's play
SET QUOTED_IDENTIFIER OFF select '''My Name is Manoj''' as Col1, 'Let''s play' as Col2 -- (1 row(s) affected)
Col1 Col2
'My Name is Manoj' Let's play
–// SET ANSI_PADDING (http://msdn.microsoft.com/en-us/library/ms187403.aspx)
Controls the way the column stores values shorter than the defined size of the column, and the way the column stores values that have trailing blanks in char, varchar, binary, and varbinary data.
Syntax: SET ANSI_PADDING { ON | OFF }
-- Example 1 SET ANSI_PADDING ON create table #tempTable1 (charcol char(20), varcharcol varchar(20)) insert into #tempTable1 select 'Manoj', 'Manoj' UNION ALL select 'Pandey', 'Pandey' select '['+charcol+']' as charcol, '['+varcharcol+']' as varcharcol from #tempTable1
charcol varcharcol
[Manoj ] [Manoj]
[Pandey ] [Pandey]
-- Example 2 SET ANSI_PADDING OFF create table #tempTable2 (charcol char(20), varcharcol varchar(20)) insert into #tempTable2 select 'Manoj', 'Manoj' UNION ALL select 'Pandey', 'Pandey' select '['+charcol+']' as charcol, '['+varcharcol+']' as varcharcol from #tempTable2
charcol varcharcol
[Manoj] [Manoj]
[Pandey] [Pandey]
drop table #tempTable1 drop table #tempTable2
Other SET statements MSDN BOL: http://msdn.microsoft.com/en-us/library/ms190356.aspx





