Read Committed_Snapshot

  • "Read Committed_Snapshot" isolation level in sql has any negatives or disadvantages?

  • It does put considerable additional load on the tempdb, so be sure you're ready to handle that. The amount depends on the level of data changes you're dealing with. Other than that, I've seen no negatives and quite a few positives.

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • can we estimate required space for tempdb ? and also whether database update speed is reduced ?

  • Best suggestion I can make is to measure the number and size of your current transactions. Get a sense of the amount of data that is actively being modified and that will give you an indication of what's going to happen with tempdb.

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • If you enable READ COMMITTED SNAPSHOT in the database, it becomes the default isolation level.

    So, it can break some of your application functionality which would depend on default behavior under READ COMMITTED isolation level. I would see that could be a common problem for many existing "booking" systems...

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • Eugene Elutin (3/18/2013)


    If you enable READ COMMITTED SNAPSHOT in the database, it becomes the default isolation level.

    For clarity READ_COMMITTED_SNAPSHOT is just a mode of the READ_COMMITTED isolation level with versioning, i.e. READ_COMMITTED_SNAPSHOT is not an isolation level unto itself.

    So, it can break some of your application functionality which would depend on default behavior under READ COMMITTED isolation level. I would see that could be a common problem for many existing "booking" systems...

    Example?

    There are no special teachers of virtue, because virtue is taught by the whole community.
    --Plato

  • opc.three (3/18/2013)


    Eugene Elutin (3/18/2013)


    If you enable READ COMMITTED SNAPSHOT in the database, it becomes the default isolation level.

    For clarity READ_COMMITTED_SNAPSHOT is just a mode of the READ_COMMITTED isolation level with versioning, i.e. READ_COMMITTED_SNAPSHOT is not an isolation level unto itself.

    So, it can break some of your application functionality which would depend on default behavior under READ COMMITTED isolation level. I would see that could be a common problem for many existing "booking" systems...

    Example?

    Yeah, I'd love to see an example or two as well.

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • Grant Fritchey (3/18/2013)


    opc.three (3/18/2013)


    Eugene Elutin (3/18/2013)


    If you enable READ COMMITTED SNAPSHOT in the database, it becomes the default isolation level.

    For clarity READ_COMMITTED_SNAPSHOT is just a mode of the READ_COMMITTED isolation level with versioning, i.e. READ_COMMITTED_SNAPSHOT is not an isolation level unto itself.

    So, it can break some of your application functionality which would depend on default behavior under READ COMMITTED isolation level. I would see that could be a common problem for many existing "booking" systems...

    Example?

    Yeah, I'd love to see an example or two as well.

    Ok, I'll try to come up with one hypothetical one.

    But at first I need to put few sentences:

    1. "booking" system could be actually any transactional system. I just held an example in my head which would be relevant for booking or stock management.

    2. I guess many will agree that READ_COMMITTED_SNAPSHOT is not a magic bullet against all locking problems in your database! When you design and code you should be aware of locking issues and design/code appropriately.

    Now an example. "booking" system...

    Let say Customer "A" does want to book one Seat and his highest priority is to book a seat #1. At the same (or almost the same) time Customer "B" wants top do exactly the same!

    So small setup:

    CREATE TABLE Booking (ID INT IDENTITY(1,1), SeatID INT, CustomerID CHAR(1))

    INSERT Booking SELECT 1, NULL

    INSERT Booking SELECT 2, NULL

    Now let see how booking system will process reservations without READ_COMMITTED_SNAPSHOT:

    ALTER DATABASE MyDev

    SET ALLOW_SNAPSHOT_ISOLATION OFF;

    ALTER DATABASE MyDev

    SET READ_COMMITTED_SNAPSHOT OFF;

    For a Customer A, started first - hence his transaction begins first (SSMS query window 1):

    BEGIN TRANSACTION

    -- Book seat 1 if it's not already taken

    IF NOT EXISTS (SELECT 1 FROM Booking WHERE SeatID = 1 AND CustomerID IS NOT NULL)

    BEGIN

    UPDATE Booking SET CustomerID = 'A' WHERE SeatID = 1

    END

    -- Now let say we need to do something else as part of the booking transaction which

    -- takes some considerate amount of time for this Customer

    -- do not commit for now!

    So, while transaction for Customer "A" is still running Customer "B" presses the "Book" button, so his transaction kick's in (SSMS query window 2):

    BEGIN TRANSACTION

    -- Book seat 1 if it's not already taken (and it's not as transaction for Customer A is not committed as yet).

    IF NOT EXISTS (SELECT 1 FROM Booking WHERE SeatID = 1 AND CustomerID IS NOT NULL)

    BEGIN

    UPDATE Booking SET CustomerID = 'B' WHERE SeatID = 1

    END

    -- Now let say that "something else - part" for Customer "B" takes no time and transaction is completed, so:

    COMMIT TRANSACTION

    Yeah, our second transaction is running as it cannot commit waiting for the first one to release the lock. Lets do it. Add COMMIT TRANSACTION into first query (SSMS window 1) and execute it.

    So. All transactions are now committed (you can check window 2). Let see what we have in result?

    SELECT * FROM Booking

    As expected we have:

    IDSeatIDCustomerID

    11A

    22NULL

    Now turn is for READ_COMMITTED_SNAPSHOT (make sure that you have only one connection to your database open, otherwise SET READ_COMMITTED_SNAPSHOT OFF will run for ever ;-)):

    ALTER DATABASE MyDev

    SET ALLOW_SNAPSHOT_ISOLATION ON

    ALTER DATABASE MyDev

    SET READ_COMMITTED_SNAPSHOT ON

    Repeat all steps in exactly the same order as previously.

    Check results.

    Surprise!!!!

    You will have Customer "B" much more lucky this time!

    Oops....

    Yes, you will tell me that my code is not good enough, and you will be right - it's a crap code.

    But that is not a point I wanted to make. What I've tried to say is:

    If you have a crap code which did work without READ_COMMITTED_SNAPSHOT, you will still get it working fine with READ_COMMITTED_SNAPSHOT ON, except one caveat: it may produce a bit different results...

    So, refer to the point #2 at the beginning of my post.

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • Grant Fritchey (3/18/2013)


    ... or two as well.

    Googled out the second one (surprisingly to me - based on "stock management":

    http://www.jimmcleod.net/blog/index.php/2009/08/27/the-potential-dangers-of-the-read-committed-snapshot-isolation-level/

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • Eugene Elutin (3/18/2013)


    Grant Fritchey (3/18/2013)


    opc.three (3/18/2013)


    Eugene Elutin (3/18/2013)


    If you enable READ COMMITTED SNAPSHOT in the database, it becomes the default isolation level.

    For clarity READ_COMMITTED_SNAPSHOT is just a mode of the READ_COMMITTED isolation level with versioning, i.e. READ_COMMITTED_SNAPSHOT is not an isolation level unto itself.

    So, it can break some of your application functionality which would depend on default behavior under READ COMMITTED isolation level. I would see that could be a common problem for many existing "booking" systems...

    Example?

    Yeah, I'd love to see an example or two as well.

    Ok, I'll try to come up with one hypothetical one.

    But at first I need to put few sentences:

    1. "booking" system could be actually any transactional system. I just held an example in my head which would be relevant for booking or stock management.

    2. I guess many will agree that READ_COMMITTED_SNAPSHOT is not a magic bullet against all locking problems in your database! When you design and code you should be aware of locking issues and design/code appropriately.

    Now an example. "booking" system...

    Let say Customer "A" does want to book one Seat and his highest priority is to book a seat #1. At the same (or almost the same) time Customer "B" wants top do exactly the same!

    So small setup:

    CREATE TABLE Booking (ID INT IDENTITY(1,1), SeatID INT, CustomerID CHAR(1))

    INSERT Booking SELECT 1, NULL

    INSERT Booking SELECT 2, NULL

    Now let see how booking system will process reservations without READ_COMMITTED_SNAPSHOT:

    ALTER DATABASE MyDev

    SET ALLOW_SNAPSHOT_ISOLATION OFF;

    ALTER DATABASE MyDev

    SET READ_COMMITTED_SNAPSHOT OFF;

    For a Customer A, started first - hence his transaction begins first (SSMS query window 1):

    BEGIN TRANSACTION

    -- Book seat 1 if it's not already taken

    IF NOT EXISTS (SELECT 1 FROM Booking WHERE SeatID = 1 AND CustomerID IS NOT NULL)

    BEGIN

    UPDATE Booking SET CustomerID = 'A' WHERE SeatID = 1

    END

    -- Now let say we need to do something else as part of the booking transaction which

    -- takes some considerate amount of time for this Customer

    -- do not commit for now!

    So, while transaction for Customer "A" is still running Customer "B" presses the "Book" button, so his transaction kick's in (SSMS query window 2):

    BEGIN TRANSACTION

    -- Book seat 1 if it's not already taken (and it's not as transaction for Customer A is not committed as yet).

    UPDATE Booking SET SeatNo = 1

    WHERE Customer ='B'

    AND NOT EXISTS(SELECT 1 FROM Booking WHERE SeatNo = 1) -- seat is not booked yet.

    -- Now let say that "something else - part" for Customer "B" takes no time and transaction is completed, so:

    COMMIT TRANSACTION

    Yeah, our second transaction is running as it cannot commit waiting for the first one to release the lock. Lets do it. Add COMMIT TRANSACTION into first query (SSMS window 1) and execute it.

    So. All transactions are now committed (you can check window 2). Let see what we have in result?

    SELECT * FROM Booking

    As expected we have:

    IDSeatIDCustomerID

    11A

    22NULL

    Now turn is for READ_COMMITTED_SNAPSHOT (make sure that you have only one connection to your database open, otherwise SET READ_COMMITTED_SNAPSHOT OFF will run for ever ;-)):

    ALTER DATABASE MyDev

    SET ALLOW_SNAPSHOT_ISOLATION ON

    ALTER DATABASE MyDev

    SET READ_COMMITTED_SNAPSHOT ON

    Repeat all steps in exactly the same order as previously.

    Check results.

    Surprise!!!!

    You will have Customer "B" much more lucky this time!

    Oops....

    Yes, you will tell me that my code is not good enough, and you will be right - it's a crap code.

    But that is not a point I wanted to make. What I've tried to say is:

    If you have a crap code which did work without READ_COMMITTED_SNAPSHOT, you will still get it working fine with READ_COMMITTED_SNAPSHOT ON, except one caveat: it may produce a bit different results...

    So, refer to the point #2 at the beginning of my post.

    Not sure about your setup. You aren't even using the same code between sessions.

  • Oops, too many windows. Post edited!

    Actually, the code version you have seen for window 2, was a good code example, which would work properly with any isolation level...

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • Eugene Elutin (3/18/2013)


    Grant Fritchey (3/18/2013)


    ... or two as well.

    Googled out the second one (surprisingly to me - based on "stock management":

    http://www.jimmcleod.net/blog/index.php/2009/08/27/the-potential-dangers-of-the-read-committed-snapshot-isolation-level/

    OK. For a lock control system as outlined, this would be a nightmare. No question.

    I'd still suggest this is on the rarer side of the spectrum (if not actually rare), but it's absolutely worth noting.

    Thanks!

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • Grant Fritchey (3/18/2013)


    Eugene Elutin (3/18/2013)


    Grant Fritchey (3/18/2013)


    ... or two as well.

    Googled out the second one (surprisingly to me - based on "stock management":

    http://www.jimmcleod.net/blog/index.php/2009/08/27/the-potential-dangers-of-the-read-committed-snapshot-isolation-level/

    OK. For a lock control system as outlined, this would be a nightmare. No question.

    I'd still suggest this is on the rarer side of the spectrum (if not actually rare), but it's absolutely worth noting.

    Thanks!

    Rarer or rare - I don't know how to judge. I've seen it happening before and not once...

    Actually, when it happens, it may take huge effort to investigate and find the reason, as code doesn't fail - it runs smoothly :hehe:

    So, thanks for agreeing that it was worth mentioning. So pity, I've made mistake in my sample on the first posting...

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • winmansoft, you should also be aware of the 14-byte-per-row overhead that READ_COMMITTED_SNAPSHOT requires. Anytime a row is updated, or a new row is inserted, the 14 bytes will be added. This can cause page splits if you don't have enough freespace in the page to hold the extra 14 bytes for each row updated.

    There is also a big initial performance hit for any "old-style" ntext, text, and image columns (but not for the newer (max) data types). After RCS is enabled, the first time one of those "old-style" large columns are updated, SQL will have to rewrite the entire value, possibly using more pages (since each page holds 40 less bytes).

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

  • when the rows will be added to tempdb(update statement, select statement) and when it is cleared ?

Viewing 15 posts - 1 through 15 (of 16 total)

You must be logged in to reply to this topic. Login to reply