Archive
Using SQL_VARIANT datatype to store any datatype value in SQL Server
According to MS BOL SQL_VARIANT can be used in columns, parameters, variables, and the return values of user-defined functions. sql_variant enables these database objects to support values of other data types.
It can have a maximum length of 8016 bytes including both the base-type information and the base-type value. Thus the maximum length of the actual base-type value is 8,000 bytes.
USE [tempdb] GO DECLARE @var SQL_VARIANT -- Set variable as DATETIME type SET @var =GETDATE() SELECT @var as Data, SQL_VARIANT_PROPERTY(@var , 'BaseType') as BaseType , SQL_VARIANT_PROPERTY(@var , 'Precision') as Precision , SQL_VARIANT_PROPERTY(@var , 'Scale') as Scale , SQL_VARIANT_PROPERTY(@var , 'TotalBytes') as TotalBytes , SQL_VARIANT_PROPERTY(@var , 'MaxLength') as MaxLength , SQL_VARIANT_PROPERTY(@var , 'Collation') as Collation;
Output:
Data BaseType Precision Scale TotalBytes MaxLength Collation
2011-01-27 17:13:53.150 datetime 23 3 10 8 NULL
-- Set variable as INT type SET @var = 1234 SELECT @var as Data, SQL_VARIANT_PROPERTY(@var , 'BaseType') as BaseType , SQL_VARIANT_PROPERTY(@var , 'Precision') as Precision , SQL_VARIANT_PROPERTY(@var , 'Scale') as Scale , SQL_VARIANT_PROPERTY(@var , 'TotalBytes') as TotalBytes , SQL_VARIANT_PROPERTY(@var , 'MaxLength') as MaxLength , SQL_VARIANT_PROPERTY(@var , 'Collation') as Collation;
Output:
Data BaseType Precision Scale TotalBytes MaxLength Collation
1234 int 10 0 6 4 NULL
-- Set variable as VARCHAR type SET @var = SYSTEM_USER SELECT @var as Data, SQL_VARIANT_PROPERTY(@var , 'BaseType') as BaseType , SQL_VARIANT_PROPERTY(@var , 'Precision') as Precision , SQL_VARIANT_PROPERTY(@var , 'Scale') as Scale , SQL_VARIANT_PROPERTY(@var , 'TotalBytes') as TotalBytes , SQL_VARIANT_PROPERTY(@var , 'MaxLength') as MaxLength , SQL_VARIANT_PROPERTY(@var , 'Collation') as Collation;
Output:
Data BaseType Precision Scale TotalBytes MaxLength Collation
XXX\mpandey nvarchar 0 0 30 256 Latin1_General_CS_AS
-- Set variable as BIT type SET @var = cast(1 as bit) SELECT @var as Data, SQL_VARIANT_PROPERTY(@var , 'BaseType') as BaseType , SQL_VARIANT_PROPERTY(@var , 'Precision') as Precision , SQL_VARIANT_PROPERTY(@var , 'Scale') as Scale , SQL_VARIANT_PROPERTY(@var , 'TotalBytes') as TotalBytes , SQL_VARIANT_PROPERTY(@var , 'MaxLength') as MaxLength , SQL_VARIANT_PROPERTY(@var , 'Collation') as Collation;
Output:
Data BaseType Precision Scale TotalBytes MaxLength Collation
1 bit 1 0 3 1 NULL
More on SQL_VARIANT: http://msdn.microsoft.com/en-us/library/ms173829.aspx
ISNULL vs COALESCE – expressions/functions in SQL Server
ISNULL & COALESCE with some common features makes them equivalent, but some features makes them work and behave differently, shown below.
– Similarity
Both can be use to build/create a CSV list as shown below:
USE [AdventureWorks] GO DECLARE @csv VARCHAR(2000) SELECT @csv = ISNULL(@csv + ', ', '') + FirstName FROM Person.Contact WHERE ContactID <= 10 ORDER BY FirstName select @csv set @csv=NULL SELECT @csv = COALESCE(@csv + ', ', '') + FirstName FROM Person.Contact WHERE ContactID <= 10 ORDER BY FirstName select @csv
Both will give the same output:
Carla, Catherine, Frances, Gustavo, Humberto, Jay, Kim, Margaret, Pilar, Ronald
– Difference #1
ISNULL accepts only 2 parameters. The first parameter is checked for NULL value, if it is NULL then the second parameter is returned, otherwise it returns first parameter.
COALESCE accepts two or more parameters. One can apply 2 or as many parameters, but it returns only the first non NULL parameter, example below.
DECLARE @str1 VARCHAR(10), @str2 VARCHAR(10) -- ISNULL() takes only 2 arguments SELECT ISNULL(@str1, 'manoj') AS 'IS_NULL' -- manoj -- COALESCE takes multiple arguments and returns first non-NULL argument SELECT COALESCE(@str1, @str2, 'manoj') AS 'COALESCE' -- manoj -- ISNULL() equivalent of COALESCE, by nesting of ISNULL() SELECT ISNULL(@str1, ISNULL(@str2, 'manoj')) AS 'IS_NULL eqv' -- manoj
– Difference #2
ISNULL does not implicitly converts the datatype if both parameters datatype are different.
On the other side COALESCE implicitly converts the parameters datatype in order of higher precedence.
-- ISNULL Does not do Implicit conversion select ISNULL(10, getdate()) as 'IS_NULL' -- Errors out
Error Message: Msg 257, Level 16, State 3, Line 1 Implicit conversion from data type datetime to int is not allowed. Use the CONVERT function to run this query.
-- COALESCE Does Implicit conversion and gets converted to higher precedence datatype.
select COALESCE(10, getdate()) as 'COALESCE' -- 1900-01-11 00:00:00.000, outputs 10 but convert it to datetime [datetime > int]
select COALESCE(getdate(),10) as 'COALESCE' -- {Current date} 2010-12-23 23:36:31.110
select COALESCE(10, 'Manoj') as 'COALESCE' -- 10 [int > varchar]
select COALESCE('Manoj',10) as 'COALESCE' -- Errors out, it does an implicit conversion, but cannot change 'Manoj' to Integer.
Error Message: Msg 245, Level 16, State 1, Line 1 Conversion failed when converting the varchar value 'Manoj' to data type int.
– Difference #3
Similar to above point ISNULL always returns the value with datatype of first parameter.
Contrary to this, COALESCE returns the datatype value according to the precedence and datatype compatibility.
DECLARE @str VARCHAR(5) SET @str = NULL -- ISNULL returns truncated value after its fixed size, here 5 SELECT ISNULL(@str, 'Half Full') AS 'IS_NULL' -- Half -- COALESCE returns full length value, returns full 12 char string SELECT COALESCE(@str, 'Half Full') AS 'COALESCE' -- Half Full
– Difference #4
According to MS BOL, ISNULL and COALESCE though equivalent, can behave differently. An expression involving ISNULL with non-null parameters is considered to be NOT NULL, while expressions involving COALESCE with non-null parameters is considered to be NULL. Thus to index expressions involving COALESCE with non-null parameters, the computed column can be persisted using the PERSISTED column attribute.
-- ISNULL() is allowed in computed columns with Primary Key CREATE TABLE T1 ( col1 INT, col2 AS ISNULL(col1, 1) PRIMARY KEY) -- COALESCE() is not allowed in non-persisted computed columns with Primary Key CREATE TABLE T2 ( col1 INT, col2 AS COALESCE(col1, 1) PRIMARY KEY)
Error Message: Msg 1711, Level 16, State 1, Line 1 Cannot define PRIMARY KEY constraint on column 'col2' in table 'T2'. The computed column has to be persisted and not nullable. Msg 1750, Level 16, State 0, Line 1 Could not create constraint. See previous errors.
-- COALESCE() is only allowed as persisted computed columns with Primary Key CREATE TABLE T2 ( col1 INT, col2 AS COALESCE(col1, 1) PERSISTED PRIMARY KEY) -- Clean up DROP TABLE T1 DROP TABLE T2
MSDN BOL links:
ISNULL: http://msdn.microsoft.com/en-us/library/ms184325.aspx
COALESCE: http://msdn.microsoft.com/en-us/library/ms190349.aspx
http://code.msdn.microsoft.com/SQLExamples/Wiki/View.aspx?title=ISNULL_COALESCE
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
DB Basics – Integrity Constraints in a Database (SQL Server)
Integrity constraints are used to ensure accuracy and consistency of data in a relational database. Data integrity allows to define certain data quality requirements that the data in the database needs to meet. If a user tries to insert data that doesn’t meet these requirements, the RDBMS will not allow so.
A Constraint is a property assigned to a column or the set of columns in a table that prevents certain types of inconsistent data values from being placed in the column(s). Constraints are used to enforce the data integrity. This ensures the accuracy and reliability of the data in the database.
CONSTRAINT = The threat or use of force to prevent, restrict, or dictate the action or thought of others.
–> There are 7 types of Constraints and they are grouped in to 4 types:
| A. ENTITY INTEGRITY | 1. Primary Key | blog post | video |
| 2. Unique Key | video | ||
| B. REFERENTIAL INTEGRITY | 3. Foreign Key | blog post | video |
| C. DOMAIN INTEGRITY | 4. NOT NULL | blog post | video |
| 5. DEFAULT | |||
| 6. CHECK | |||
| D. USER DEFINED INTEGRITY | 7. RULES | blog post | video |
–> Check the video with discussion on all these Constraints:
Creating Linked Server in SQL Server
Linked Servers provides access to external datasources be it another databases like Oracle, MySQL, or Excel files.
Advantages:
– Remote server access.
– The ability to issue distributed queries, updates, commands, and transactions on heterogeneous data sources across the enterprise.
– The ability to address diverse data sources similarly.
MSDN Links on Linked Servers:
Info: http://msdn.microsoft.com/en-us/library/ms188279(v=SQL.90).aspx
Configure: http://msdn.microsoft.com/en-us/library/aa213778(SQL.80).aspx
My idea here is to query MySQL tables in MS SQL Server as I’m more comfortable with MS SQL queries and semantics. I don’t know if or how I can use Ranking functions, case statements, etc in MySQL DB. Plus I’m also not comfortable in writing queries in DOS like editor or any other freeware tool.
Linked Server to MySQL:
Before creating a Linked Server for MySQL you need to install the MySQL ODBC connector.
Download MySQL ODBC Client: http://dev.mysql.com/downloads/connector/odbc/
Now we need a DSN that will act as a bridge between for creating the Linked Server:
Create a System DSN:
– On Control Pannel -> Admin Tools -> Data Sources (ODBC), Select System DSN tab, click ADD, Selct “MySQL ODBC 3.51 Driver”, Click Finish.
– A new pop-up will come up, “Connector/ODBC 3.51.27 – Configure Data Source Name”.
– On Login Tab: Set fields, Click Test.
– On Advanced Tab, go to following tabs and check the options:
– Flag1: Return Matching Rows, Allow Big Results, Use Compressed Protocol, Change BIGINT columns to Int, Safe
– Flag2: Don”t Prompt Upon Connect, Ignore # In Table Name
– Flag3: Return Table Names for SQLDescribeCol, Disable Transactions
– Click “OK”
Create a New Linked Server:
– On SSMS under Object Explorer go to “Server Objects” -> “Linked Servers”, Richt Click and select “New Linked Server”
– Set an appropriate name on “Linked Server”, like: MYSQL_LINK
– Server Type = Select “Other Data Source” radio button.
– Set Provider = Microsoft OLE DB Provider for ODBC Drivers
– Set the “Product Name” & “Data Source” field you set on configuring the DSN.
This can also be setup by following SQL statements:
-- Create New Linked Server EXEC sp_addlinkedserver @server = 'MYSQL_LINK', @srvproduct = 'MySQLDatabase', @provider = 'MSDASQL', @datasrc = 'MySQLKayako' -- Pull list of all Servers select * from sys.servers EXEC sp_linkedservers -- Drop the Linked Server EXEC sp_dropserver 'MYSQL_LINK'
Now you can query the tables and other objects of MySQL database by using OPENQUERY function as shown below:
-- Select a table or view SELECT * FROM OPENQUERY(MYSQL_LINK, 'select * from MySQL_Table') -- Execute a function SELECT * FROM OPENQUERY(MYSQL_LINK, 'EXEC MySQL_Proc param1, param2')
OPENQUERY() also helps in selecting a Stored Procedure result just like a table.





