Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase ««12

What happens if new records are inserted in a source table during a package execution? Expand / Collapse
Author
Message
Posted Monday, May 13, 2013 2:04 PM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Tuesday, October 28, 2014 12:50 PM
Points: 1,061, Visits: 2,580
opc.three (5/13/2013)
The issuance of the IDENTITY column is part of the transaction so we are protected from loss of data.

In SSMS, Query Window 1, run this:

USE YourDatabaseName;
DxROP TABLE dbo.StagingTable
CxREATE TABLE dbo.StagingTable (StagingTableID INT NOT NULL IDENTITY(1,1), Col1 sysname);

In Query Window 2, populate the table with some data:

BEGIN TRAN
INSERT INTO dbo.StagingTable
(
Col1
)
SELECT TOP 1000
c1.name
FROM sys.columns c1
CROSS JOIN sys.columns c2;

-- note, I am leaving the transaction open on purpose

In Query Window 3, insert a single row:

INSERT  INTO dbo.StagingTable
(
Col1
)
SELECT TOP 1
c1.name
FROM sys.columns c1
CROSS JOIN sys.columns c2;

-- note that the insert succeeds despite the fact
-- that there are 1000 rows trying to, but not yet
-- committed on another SPID

Query Window 4, along comes our SSIS Package wanting to get the MAX ID and copy the data:

SELECT  MAX(StagingTableID)
FROM dbo.StagingTable;

Nope, must wait...due to the open transaction in Window 2. Go back to Window 2 and call COMMIT or ROLLBACK, your choice, and you'll see as soon as that happens Window 4 completes immediately and returns 1001. This is the protection we need, i.e. no lost data.


Except this is not what happens when I execute this code in this manner on our 2008R2 instance. After I have executed Queries 1-3, I can see the SPID for the first insert sleeping. However, when I run Query 4, I get a result = 1001. SELECT * FROM dbo.StagingTable gives me the one row I inserted in Query 3. We're running in autocommit mode - are there other database- or instance-level settings that can affect this?


Jason Wolfkill
Blog: SQLSouth
Twitter: @SQLSouth
Post #1452308
Posted Monday, May 13, 2013 2:54 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: 2 days ago @ 8:04 PM
Points: 7,141, Visits: 12,768
If you are using either Snapshot Isolation or READ COMMITTED SNAPSHOT ISOLATION (RCSI) mode that could account for the behavior you are seeing. My comments are related to the default iso level, READ COMMITTED, with RCSI OFF.

__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato
Post #1452326
Posted Monday, May 13, 2013 3:30 PM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Tuesday, October 28, 2014 12:50 PM
Points: 1,061, Visits: 2,580
opc.three (5/13/2013)
If you are using either Snapshot Isolation or READ COMMITTED SNAPSHOT ISOLATION (RCSI) mode that could account for the behavior you are seeing. My comments are related to the default iso level, READ COMMITTED, with RCSI OFF.


Ah - we are indeed running with READ_COMMITTED_SNAPSHOT set to ON.


Jason Wolfkill
Blog: SQLSouth
Twitter: @SQLSouth
Post #1452340
Posted Monday, May 13, 2013 4:42 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: 2 days ago @ 8:04 PM
Points: 7,141, Visits: 12,768
wolfkillj (5/13/2013)
opc.three (5/13/2013)
If you are using either Snapshot Isolation or READ COMMITTED SNAPSHOT ISOLATION (RCSI) mode that could account for the behavior you are seeing. My comments are related to the default iso level, READ COMMITTED, with RCSI OFF.


Ah - we are indeed running with READ_COMMITTED_SNAPSHOT set to ON.

This has been a good reminder (at least for me) that when row versioning is involved that some concurrency scenarios will play out differently than without, and it really needs to be considered carefully. I could certainly have made it explicit in my post that I was making the assumption that default iso level and no RCSI was what I was assuming, and in the future on threads like this where it matters I will certainly start doing that. Thanks for confirming wolfkillj. Mystery solved.


__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato
Post #1452358
« Prev Topic | Next Topic »

Add to briefcase ««12

Permissions Expand / Collapse