December 31, 2012 at 12:25 am
Hi,
I am new to this DB Development.
Please advice, why we need this "SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;" while creating SPs.
Regards,
Nagesh Prasad
December 31, 2012 at 1:52 am
You don't need it and frankly you probably shouldn't be using readuncommitted without a very good reason.
See - http://blogs.msdn.com/b/davidlean/archive/2009/04/06/sql-server-nolock-hint-other-poor-ideas.aspx
(nolock is much the same as read uncommitted, just one's a hint)
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
August 2, 2013 at 1:49 am
For SQL Reports stored procedures you most definitely want to use "SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED".
You only specify it once in the beginning of your stored procedure, as to having to specify with(NOLOCK) in every from clause in your stored procedure, a real time saver.
-------------------------------------------------------------------------------
SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
SELECT
firstname
,salary
FROM dbo.employee e
JOIN salary s
ON s.employeeid = s.employeeid;The comparable method using hints would be:
-------------------------------------------------------------------------------
SELECT
firstname
,salary
FROM dbo.employee e WITH (nolock)
JOIN salary s WITH (nolock)
ON s.employeeid = s.employeeid;
-------------------------------------------------------------------------------
August 2, 2013 at 3:09 am
kevin_nikolai (8/2/2013)
For SQL Reports stored procedures you most definitely want to use "SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED".
Because it's really, really important for all reports to occasionally return inconsistent and incorrect data? I mean, one would never expect a report to actually be correct all the time, that's just not realistic....
See - http://blogs.msdn.com/b/davidlean/archive/2009/04/06/sql-server-nolock-hint-other-poor-ideas.aspx
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
August 2, 2013 at 3:34 am
kevin_nikolai (8/2/2013)
For SQL Reports stored procedures you most definitely want to use "SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED".--
If you can guarantee that the database is and will be in a fully committed and unchanging state when the proc runs (eg if everything is in read-only mode), this should be OK. Otherwise Gail's advice is most pertinent.
The absence of evidence is not evidence of absence.
Martin Rees
You can lead a horse to water, but a pencil must be lead.
Stan Laurel
August 2, 2013 at 6:35 am
Phil Parkin (8/2/2013)
If you can guarantee that the database is and will be in a fully committed and unchanging state when the proc runs (eg if everything is in read-only mode)
And if the DB is guaranteed to be essentially read-only at the time, then there's no real point in read uncommitted as there will be no exclusive locks that could block the report.
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
August 2, 2013 at 11:54 am
OK,
In SQL 2012 you can have a read-only copy of the database - which you can use for SQL Reports,
in this case you can use READ UNCOMMITTED or skip it altogether (according to Gail).
Normally you would use READ UNCOMMITTED in stored procedures of SQL Reports if they point
to Application server database - NOT to impact performance of the Application you would not worry too much about the totals that are slightly out
(I know best case scenario is not to run reports from Application server databases - but in reality not all companies can afford a data warehouse or data warehouse skilled employees).
August 2, 2013 at 12:00 pm
kevin_nikolai (8/2/2013)
Normally you would use READ UNCOMMITTED in stored procedures of SQL Reports if they pointto Application server database - NOT to impact performance of the Application you would not worry too much about the totals that are slightly out
And the users of those reports know and accept that the results could be completely wrong. Not slightly off due to dirty reads, potentially way off due to missing and re-reading rows.
I've seen a report whose total was 20% off because nolock had allowed a particular row to be read twice and totalled twice into a financial report. Personally I've never met users who would be happy with reports that they know could be wrong. I have however met lots of developers who had no idea what side effects nolock/read uncommitted could have and who would close bug reports about incorrect data as 'cannot reproduce'.
p.s. Snapshot isolation. Read committed snapshot isolation. Database Snapshot. Reporting off log shipping secondary. Reporting off mirror DB. Reporting off Always On Read-only Secondary in SQL 2012.
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
August 2, 2013 at 12:09 pm
Hi Gail, thanks for the reply, just want to confirm the following:
I assume I should rather use these -
Snapshot isolation.
Read committed snapshot isolation.
Database Snapshot.
I assume you meant don't use the following -
Reporting off log shipping secondary.
Reporting off mirror DB.
Reporting off Always On Read-only Secondary in SQL 2012.
August 2, 2013 at 12:20 pm
No, I'm giving you alternatives to using nolock. Which you use is up to you, all will give you accurate reports (accurate to specific points in time for some) without taking shared locks on your application DB.
Snapshot isolation. Read committed snapshot isolation. Database Snapshot. Reporting off log shipping secondary. Reporting off mirror DB. Reporting off Always On Read-only Secondary in SQL 2012.
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
August 12, 2013 at 5:32 am
kevin_nikolai (8/2/2013)
SELECTfirstname
,salary
FROM dbo.employee e WITH (nolock)
JOIN salary s WITH (nolock)
ON s.employeeid = s.employeeid;
And when your colleagues get short paid because you thought it essential to put NOLOCK onto a "report" query?
Viewing 11 posts - 1 through 10 (of 10 total)
You must be logged in to reply to this topic. Login to reply