Category Archives: #SQLServer

All about Microsoft SQL Server

#0204 – SQL Server – SET options – PARSEONLY – Parse a T-SQL query/batch but do not compile or execute it


What would you do if you wanted to check whether a particular query/batch you wrote is free from any errors without using Intelli-sense and without executing or compiling the statement?


It’s a fairly simple question for anyone who has worked with SQL Server for a considerable amount of time. You would use the tiny blue check-box besides the “Execute” and “Debug” buttons on the SSMS toolbar, right?







image
Parse button on the SSMS for SQL 2012 toolbar

SET PARSEONLY


Well, if you are a keyboard-savvy developer (like me), you would use a SET option. SET options allow us to change the behaviour of SQL Server for the current session with respect to handling of specific information like date and time values, locking, Query execution, transaction, ISO settings and Statistics.


One such option is the SET PARSEONLY option, which when set to ON, parses a T-SQL query/batch for errors without executing or compiling the query/batch.


Let’s do a simple test to confirm if this indeed works or not. After parsing the query using the PARSEONLY option, we will attempt to see if a cached plan was generated for the query. If the query compiles or gets executed, an entry would exist for the cached plan.

USE AdventureWorks2012
GO

--Set PARSEONLY to ON, indicating that the query should not be compiled or executed
SET PARSEONLY ON

SELECT '1' AS RoundNum,
       Employee.BusinessEntityID,
       Employee.BirthDate,
       Employee.Gender,
       Employee.JobTitle
FROM HumanResources.Employee AS Employee;
GO

--Set PARSEONLY to OFF
SET PARSEONLY OFF

--Check for caching of the query plan. 
--If the query was compiled, an entry would be available here
SELECT '1' AS RoundNum, usecounts, cacheobjtype, objtype, text 
FROM sys.dm_exec_cached_plans 
CROSS APPLY sys.dm_exec_sql_text(plan_handle) 
WHERE usecounts > 0 AND 
        text like '%FROM HumanResources.Employee%'
    AND text NOT LIKE '%Check%'
ORDER BY usecounts DESC;
GO

Execution of both the queries succeed, but no records are returned by the 2nd query (one which returns cached plans). Checking the “Messages” tab also tells us that no records were returned back to the client, indicating that the first query was only parsed, but not compiled or executed.


image


image


Please NOTE:



  1. The SET option – PARSEONLY is set at parse time, and not at execution or run-time. Hence, please do not use this inside a stored procedure or a trigger
  2. Successful parsing of a query does not protect against:


    • Incorrect object names
    • Any logical or business-rule related errors that may exist

  3. Hence, before integrating your code changes into source control, please make sure that you unit test your queries/batches by setting PARSEONLY to OFF


Until we meet next time,


Be courteous. Drive responsibly.

#0203 – SQL Server 2012 – Deploy local Help/Books-On-Line collection-Instructions


Recently, Pinal Dave, a.k.a SQLAuthority (B|T) wrote a piece about Managing Help settings in the SSMS for SQL Server 2012. That post prompted me to write this post around local deployment of the SQL Server Books On Line collection for SQL Server 2012.


The SSMS for SQL Server 2012 comes with very visible UI changes. For starters, it comes with the Visual Studio 2010 shell (if you would like to know more about the capabilities of the SSMS, please follow my 10-part tutorial on the topic here: Getting started with SSMS). One of the other major differences is that the Books-On-Line or Help collection is no longer available locally (i.e. deployed on the client machine) by default. The default mode for the help is online.


There are at least two benefits that I can see from having the help online:



  1. Saves space on the client machine
  2. One never has out-of-date help content, because the help is online!

There are however, a few instances wherein you would prefer to have the help installed locally. For example, when you would like to work while travelling or in case the IT policy at your office does not allow open Internet access. For such circumstances, the SSMS for SQL Server 2012 does allow the help collection to be deployed locally, which is what I will be demonstrating through this post.


Pre Requisite


Download and extract the contents of Product Documentation for Microsoft SQL Server 2012 for firewall and proxy restricted environments. This is approximately a 200MB download, so please check your available bandwidth and data plan costs before proceeding with the download.


Steps to install & configure local help











image
Press the key combination “Ctrl+Alt+F1” or go to Help –> Manage Help Settings
image
The Help Library Manager would be launched

Installing Help from local source


Once the offline product documentation has been extracted, you can use the following steps to install:























image
Choose to “Install Content from disk”
image
Select the “HelpContentSetup.msha” file from the extracted offline documentation.
image
Click “Next” and choose to “Add” any/all help packages of your choice
image
Click “Update” to begin extraction and deployment of the local help content
image
Once the installation is complete, click “Finish”


Installing Help from online source


If you do not want to download the entire 200MB help/product documentation package, you can also install it from an online source. This mode allows you to choose the specific topics for which you would like to download the help.















image
Choose “Install Content from Online” on the Help Library Manager window.
image
The system fetches the product group and associated production documentation material listing.
image
Choose “Add” to add the documentation to the download and install list. Notice that upon clicking “Add”, the status changes to “Update pending” indicating that the content will be updated from the online store when the user presses “Update” button (similar to offline install shown above).

Configuring online v/s local help collection usage




Once that the local help collection is downloaded and deployed, users can choose to switch from online to local help mode.











image
Click on “Choose online or local help” in the Help Library Manager
image
Set your preferred Help experience and click “OK”. You are now ready to use your newly downloaded local help collection.


Until we meet next time,


Be courteous. Drive responsibly.

#0202-SQL Server-Replacing EXECUTE with sp_executesql does not protect against SQL injection


There are many dangers that come from incomplete knowledge, or for that matter, from the lack of experimenting something on your own. Implementing a solution without proper understanding and testing is a sin that most of us developers have committed at some point (knowingly, or unknowingly).


One such point is ensuring that a system is protected from SQL injection. As the name suggests, SQL injection refers to the ability of an external attacker to inject a rogue SQL command to the database (e.g. dumping the contents of the database to the user) within a seemingly legitimate request. Allow me to demonstrate what I mean by this.


(Please note that the intention of this post is to bust a myth around protecting against SQL injection and is not intended to be a complete guide against SQL injection).


[EDIT: 2012-10-08, 23:10 IST: The examples in this post are intentially over simplified for a clear understanding of the concept. The situation described in this post does not generally mandate the use of dynamic queries. END EDIT]


SQL Injection – A demo


Assume that my application provides functionality to search for contacts stored in the system based on the last name. This requirement is realized in code, by the following stored procedure:

USE AdventureWorks2012
GO

–Safety check
IF OBJECT_ID(‘proc_SearchPersonByLastName’) IS NOT NULL
DROP PROCEDURE dbo.proc_SearchPersonByLastName
GO

–Create Test Procedure, prone to injection
CREATE PROCEDURE dbo.proc_SearchPersonByLastName
@filterString NVARCHAR(100)
AS
BEGIN
SET NOCOUNT ON;
DECLARE @sqlstring NVARCHAR(200);
SET @sqlstring = ‘SELECT BusinessEntityID, PersonType, Title, FirstName, MiddleName, LastName, EmailPromotion
FROM Person.Person
WHERE LastName = ”’;

SET @sqlstring = @sqlstring + @filterString + ””;

BEGIN TRY
EXEC (@sqlstring);
END TRY
BEGIN CATCH
SELECT ERROR_MESSAGE(),
ERROR_NUMBER(),
ERROR_SEVERITY(),
ERROR_STATE();
–THROW is SQL 2012 specific!
–If you are running SQL 2008, please replace it with RAISERROR
–http://beyondrelational.com/modules/2/blogs/77/posts/11287/sunset-for-raiserror-and-sunrise-for-throw-sql-11-denali.aspx
THROW;
END CATCH
END
GO


What the stored procedure does is to append the filter criteria to the query and then uses EXEC or EXECUTE to execute the query. Here’s what can go wrong. Imagine that an attacker uses the following call:

–SQL Injection!
EXEC proc_SearchPersonByLastName ‘Hill” OR 1=1 OR 1=”%’
GO

The result? All contents of the table Person.Person are dumped out to the user because 1 will always be equal to 1 – something which the system is not supposed to do! This is a simple demonstration of a SQL injection attack. For more such examples, refer the links in the References section of this post.


Image showing that all records from Person.Person have been dumped to the user


(One of the) Solutions – the myth


The above is a classic example of SQL injection and one of the most common myths that surrounds SQL Injection is that it is due to the use of EXEC or EXECUTE. Some say – “simply replace EXEC with calls to sp_executesql and the system becomes SQL injection-proof”. This has to be the biggest misconception of all times around this subject.


Let’s simply replace EXEC with a call to sp_executesql and we see that SQL injection is still possible.

USE AdventureWorks2012
GO
–Alter Test Procedure, still prone to injection
ALTER PROCEDURE dbo.proc_SearchPersonByLastName
@filterString NVARCHAR(100)
AS
BEGIN
SET NOCOUNT ON;
DECLARE @sqlstring NVARCHAR(200);
SET @sqlstring = ‘SELECT BusinessEntityID, PersonType, Title, FirstName, MiddleName, LastName, EmailPromotion
FROM Person.Person
WHERE LastName = ”’;

SET @sqlstring = @sqlstring + @filterString + ””;

BEGIN TRY
–Notice that we now use sp_executesql here
EXEC sp_executesql @sqlstring;
END TRY
BEGIN CATCH
SELECT ERROR_MESSAGE(),
ERROR_NUMBER(),
ERROR_SEVERITY(),
ERROR_STATE();
–THROW is SQL 2012 specific!
–If you are running SQL 2008, please replace it with RAISERROR
–http://beyondrelational.com/modules/2/blogs/77/posts/11287/sunset-for-raiserror-and-sunrise-for-throw-sql-11-denali.aspx
THROW;
END CATCH
END
GO

–Proof that injection is possible
EXEC proc_SearchPersonByLastName ‘Hill” OR 1=1 OR 1=”%’
GO


Simply replacing EXEC with sp_executesql does not prevent SQL injection


(One of the) Solutions – Parameterization


Using sp_executesql instead of EXEC is a partial solution. Using sp_executesql with parameters is the complete solution. Allow me to demonstrate. I have modified the stored procedure from above to use parameters:

USE AdventureWorks2012
GO
–Now, alter the SP to protect from injection
ALTER PROCEDURE dbo.proc_SearchPersonByLastName
@filterString NVARCHAR(100)
AS
BEGIN
SET NOCOUNT ON;
DECLARE @sqlstring NVARCHAR(200);
DECLARE @params NVARCHAR(100);
SET @sqlstring = ‘SELECT BusinessEntityID, PersonType, Title, FirstName, MiddleName, LastName, EmailPromotion
FROM Person.Person
WHERE LastName = @personLastName’;
SET @params = ‘@personLastName NVARCHAR(100)’;

BEGIN TRY
EXEC sp_executesql @sqlstring,
@params,
@personLastName = @filterString;
END TRY
BEGIN CATCH
SELECT ERROR_MESSAGE(),
ERROR_NUMBER(),
ERROR_SEVERITY(),
ERROR_STATE();
THROW;
END CATCH
END
GO


What I have done is that I have explicitly specified that the query should expect a single parameter with a specific type – anything more is considered invalid and should not be processed. So, let me try it out:

USE AdventureWorks2012
GO
–Try injecting SQL code again – Won’t Work!
EXEC proc_SearchPersonByLastName ‘Hill” OR 1=1 OR 1=”%’
GO

sp_executesql with parameters protects agaisnt SQL injection


This call did not work because the statement expects just one parameter and is instead getting a complete condition – which is incorrect. The following correct call however, works:

–Proper call – success
EXEC proc_SearchPersonByLastName ‘Hill’
GO

sp_executesql with parameters protects agaisnt SQL injection


The conclusion that we can derive from this exercise is that to protect from SQL injection, one of the first things that need to be done is to use sp_executesql with parameterization. Simply replacing EXEC or EXECUTE calls with sp_executesql is not the solution.


References:



Until we meet next time,


Be courteous. Drive responsibly.

#0201-SQL Server-UPDATE statement-use .WRITE for partial updates


Some of you might already know about the .WRITE clause in the UPDATE statement, but I just learnt about it the other day and would therefore like to share about it for the benefit of all.

Almost every system has a couple of system default values that get populated each time a new database for the product is created/initialized. The system that I work on is no different. In a particular release, we needed to reword some of the terminologies in our product. For the purposes of this post, let’s assume that we needed to update the usage of “SQL Server” to read “Microsoft SQL Server”.

The Scenario

To keep things simple, allow me to create a table with a single record.

USE tempdb
GO
--Safety Check
IF OBJECT_ID('UpdateWRITETest') IS NOT NULL
    DROP TABLE dbo.UpdateWRITETest
GO

--Create test table
CREATE TABLE dbo.UpdateWRITETest (ProductDescription VARCHAR(MAX))
GO

--Insert test data
INSERT INTO dbo.UpdateWRITETest (ProductDescription)
VALUES ('SQL Server has a long history as the relational database solution from Microsoft.'),
       ('Find information about previous versions of SQL Server, including product details, technical resources, and support information.');
GO

Normally, one would have used one of the following mechanisms (there are many possible variants, based on individual preference) for the updates to default data.

The Conventional Solutions

The possible conventional solutions involve the use of REPLACE and the STUFF functions.

USE tempdb
GO
--Method 01
UPDATE upd
SET upd.ProductDescription = REPLACE(ProductDescription,'SQL Server','Microsoft SQL Server')
FROM dbo.UpdateWRITETest AS upd
GO

--Method 02
UPDATE upd
SET upd.ProductDescription = STUFF(ProductDescription,CHARINDEX('SQL Server',ProductDescription,1),LEN('SQL Server'),'Microsoft SQL Server')
FROM dbo.UpdateWRITETest AS upd
GO

The UPDATE statement – .WRITE clause

However, a close friend suggested I relook the Books On Line page of the UPDATE statement. Since his statements are often cryptic, I opened up the help for the UPDATE statement and found the .WRITE clause. Notice that I deduct 1 from the value returned by CHARINDEX (i.e. the position of the search string). This is because .WRITE uses a 0-based position index.

USE tempdb
GO
--UPDATE .WRITE method
UPDATE upd
SET ProductDescription .WRITE('Microsoft SQL Server',(CHARINDEX('SQL Server',ProductDescription,1)-1),LEN('SQL Server'))
FROM dbo.UpdateWRITETest AS upd
GO

Using .WRITE to replace only part of a string

Features:

While functionally similar to the more generic STUFF statement, the .WRITE clause is an integral part of the UPDATE statement, and has the following features:

  • Works for VARCHAR(MAX), NVARCHAR(MAX) and VARBINARY(MAX)
  • .WRITE performs a partial or full update
    • For example, if only the first 200 characters of a large string value are to be updated, a partial update would be performed
    • This prevents delete and subsequent modification of all data in the column, which would happen in the case of REPLACE
  • Exceptions to .WRITE being a partial update are taken when
    • Changes are made to key columns of a partitioned view or table
    • Modifies more than one row and also updates the key of a nonunique clustered index to a nonconstant value
  • If the statement inserts or appends new data, the operation is minimally-logged if the database recovery model is simple or bulk-logged
    • Updates to existing data are not minimally-logged
  • .WRITE cannot be used to update a NULL column or set the value of a column to NULL

Because the .WRITE clause performs a partial update, I am researching more into the performance aspects of the .WRITE statement. I will write a follow-up post once the research is complete.

Reference:

Until we meet next time,

Be courteous. Drive responsibly.

#0200-SQL Server-Permissions for SQL Server Profiler-Required access for a user/login


I trust that all you are finding my tutorial series on the SQL Server Profiler useful. Recently, I received an interesting question related to assigning permissions to a SQL Server user to allow them to use the SQL Server Profiler.


Today, using a simple experiment, I will be demonstrating the following:



  1. What minimal permissions are required for a user to capture SQL traces using the SQL Server profiler?
  2. How to assign these minimum permissions to a SQL Server user?

The Demo


To begin with establishing an environment for the experiment, I will first create a SQL Server login and a user associated to that login.

–Creating the logins/users
USE master
GO
CREATE LOGIN ProfilerTest01
WITH PASSWORD = ‘Passwd@12’, CHECK_EXPIRATION = OFF, CHECK_POLICY = OFF, DEFAULT_DATABASE = AdventureWorks2008R2
GO
USE AdventureWorks2008R2
GO
CREATE USER ProfilerTest01
FOR LOGIN ProfilerTest01
GO

Normal logins/users cannot run the Profiler


I will now launch the SQL Server Profiler and attempt to login using this newly created login/user – ProfilerTest01. The error message that I receive is:


The SQL Server Profiler can only be used by a member of sysadmin fixed server role or have the ALTER TRACE permissions


Looking at the message again indicates that in order to allow this user to use the SQL Server Profiler, I have a choice in either providing the user sysadmin fixed server role access (not advised) or grant the ALTER TRACE permission.


In order to run a trace against SQL Server you must be a member of sysadmin fixed server role or have the ALTER TRACE permission.


Not Recommended: Providing sysadmin fixed server role access is not recommended because it would grant the login/user complete control over the entire SQL Server instance and therefore does not go with the “minimum permissions” paradigm.


The only choice therefore is to provide the user ALTER TRACE permissions.


Solution – Assign the ALTER TRACE permissions


The solution therefore is to assign ALTER TRACE permissions to the login using the following GRANT statement. The ALTER TRACE permission is a server-scoped permission being granted to a server-level principal (a login) which means that granting somebody this permission will expose the entire SQL Server instance for the mentioned purpose (in this case, tracing).

–Granting permissions to the logins/users
USE master
GO
GRANT ALTER TRACE TO ProfilerTest01
GO

It is important here to switch back to the master database because the permission that we are attempting to grant is a server scoped permission and therefore not being in the master database can result in the following error:


Msg 4621, Level 16, State 10, Line 1


Permissions at the server scope can only be granted when the current database is master


Now that I have executed the script to GRANT the ALTER TRACE permission, I will now attempt to use the SQL Server Profiler with this login. I can see that the login succeeded and the Profiler brought the trace properties window.


After configuring the trace (Part 02-Customizing Profiler Templates), I execute the following test statements below while the Profile trace is running. The test statements are random queries for demonstration only.

–Test Workload (Login to the Profiler with the test login before executing the workload)
USE AdventureWorks2008R2
GO
SELECT * FROM HumanResources.Employee
GO

USE master
GO
SELECT * FROM sys.configurations
GO

USE msdb
GO
SELECT * FROM sys.systypes
GO

USE AdventureWorksLT
GO
SELECT * FROM BuildVersion
GO


SQL Server Profiler showing captured traces from all databases due to the ALTER TRACE server-scoped permission


SECURITY WARNING! The key point to note here is that I am executing queries against multiple databases in the system. The login running the trace does not have permissions to the “AdventureWorksLT” database, yet queries executed against that database can be traced by the user in the Profiler. This is because the ALTER TRACE is a server-scoped permission as mentioned above.


SQL Logins v/s Windows Logins


While the experiment above was demonstrated using SQL Logins, the process remains the same if SQL logins mapped to a Windows logins are to be used. I trust that these steps will help you grant Profiler permissions to your development team without having to make them sysadmins on your SQL Server instances.


References:



Until we meet next time,


Be courteous. Drive responsibly.