Foreign Key Violations During Insert in Transaction

T

Tyrant Mikey

I could use some help regarding transactions.

I am using the System.Data.SqlClient namespace to work with a SQL
Server 2000 database. In the database I have 2 tables that are related
to one another. One table holds a facility (a location), and the other
holds a list of programs (services) that are provided by that facility.

When a new facility is created, I start a transaction, write the
facility, and then attempt to insert each of the programs (with a
reference to the parent facility). However, I am experiencing a
SqlException when I try to insert the program ("INSERT statement
conflicted with COLUMN FOREIGN KEY constraint" between the facility
table and the program table).

Now, I've looked at this until I'm blue in the face. Both inserts are
running on the same connection and transaction, so I had assumed that
everything would work just fine. But that is apparently not the case.

My theory is this:

The ID for the facility is an IDENTITY column, which, of course, won't
*really* exist until the transaction is committed. I am trying to
insert a program with it's FacilityID column set to the newly created
ID from the facility, and that's the rub. SQL doesn't think it exists.

I was under the impression that, because they both take place in the
same transactional context, the insert would work because the ID exists
in the TRANSACTION.

Am I wrong?
 
D

David Sceppa

I'd use the term "misguided" rather than "wrong". When you insert the
parent row into the database, SQL Server generates a new identity value.
Yes, that value does really exist even before you commit the transaction.

Let's say that when you start a transaction, the last identity value
generated was 10. You start the transaction, insert a new row, which gets
an identity value of 11. If you rollback the transaction, that value of 11
is gone. The next identity value the server generates will be 12. While
this frustrates some developers who don't like seeing the "holes" in the
values due to rolled back transactions, the behavior makes a lot of sense
when you consider that you might have multiple connections to the database
at any given time, each with an open transaction and a pending insert.

Meanwhile, back to the issue at hand... You have an open transaction
and you've inserted the new parent row. When the time comes to insert the
child rows, you still need to use the new identity value from the parent
row in the FK column for your child row.

Assuming you're using SQL Server 2000 (or a beta of 2005), you would
issue a SELECT SCOPE_IDENTITY() query, which retrieves the last identity
value generated on your connection. If you're using SQL Server 7.0, you'll
need to use SELECT @@IDENTITY. See the SQL Server 2000 Books OnLine for a
discussion as to why SCOPE_IDENTITY is preferable.

Here's a canned reply that has helped answer a lot of questions on
this topic in the past. The focus is on retrieving the newly generated
identity values and using them in the child rows.

I hope this information proves helpful.

David Sceppa
Microsoft
This posting is provided "AS IS" with no warranties,
and confers no rights. You assume all risk for your use.
© 2005 Microsoft Corporation. All rights reserved.


This is a fairly common scenario that ADO.NET handles much
better than any of its predecessors. It may seem complex at
first, but once you've handled the scenario once, it will
hopefully feel more intuitive.


1.) How do I keep pending parent and children in synch?

Set the ADO.NET DataColumn's AutoIncrement property to True
and ADO.NET will generate placeholder values for new rows. The
new values depend on the AutoIncrementStep, AutoIncrementSeed,
and the last value used in the DataTable. I recommend setting
AutoIncrementSeed and AutoIncrementStep to -1. These settings
will generate placeholder values of -1, -2, -3, … There are two
benefits to this approach. The values won't conflict with any
that actually exist in the database. The user will not
misinterpret the placeholder value as an actual value from the
database.

As you add the parent rows and ADO.NET generates placeholder
values, use those placeholder values for your pending child rows.
The DataRelation object will make it easy to go from parent to
child and back, either in code or in bound controls.


2.) How do I fetch the new key values for the parent rows as I
submit them?

If you're using SQL Server, this process is actually very
simple. If you were writing your own queries, you would execute
an "INSERT INTO…" query to insert the new row and then execute a
"SELECT SCOPE_IDENTITY()" query to retrieve the last identity
value generated on that connection.

The DataAdapter submits changes via its InsertCommand
property. You can append ";SELECT @@IDENTITY AS MyIDColumn" to
the end of the "INSERT INTO..." query. (SQL 2000 users should
use "SELECT SCOPE_IDENTITY()..." instead of "SELECT @@IDENTITY".
See SQL Server Books OnLine for more information on why.) If
you're building your DataAdapters via Visual Studio .NET's
DataAdapter Configuration Wizard, the wizard will do this for you
automatically.

If you're writing your code by hand, make sure the
InsertCommand's UpdatedRowSource property is set to Both (the
default) or FirstReturnedRecord. This property controls whether
the DataAdapter will fetch the row returned by the query and
apply that data to the DataRow object.

This functionality is possible because SQL Server allows you
to execute a batch of queries that returns rows. However, not
all databases support this feature.

If you're working with an Access database, you'll need to go
a slightly different route. Trap for the DataAdapter's
RowUpdated event and use code to check for a successful insert.
Execute the "SELECT @@IDENTITY" query using a Command object and
assign the value returned by the query to the appropriate column
and call the DataRow object's AcceptChanges method. Your code
will look something like this:

Visual Basic .NET:
Dim da As New OleDbDataAdapter(strSQL, strConn)
Dim cn As OleDbConnection = da.SelectCommand.Connection
Dim cmdGetIdentity As New OleDbCommand("SELECT @@IDENTITY", cn)
AddHandler da.RowUpdated, AddressOf HandleRowUpdated
Dim tbl As DataTable = CreateMyDataTable()
da.Fill(tbl)
...
da.Update(tbl)

Private Sub HandleRowUpdated(ByVal sender As Object, _
ByVal e As
OleDbRowUpdatedEventArgs)
If e.Status = UpdateStatus.Continue AndAlso _
e.StatementType = StatementType.Insert Then
e.Row("OrderID") =
Int32.Parse(cmdGetIdentity.ExecuteScalar().ToString())
e.Row.AcceptChanges()
End If
End Sub

Visual C# .NET:
OleDbDataAdapter da = new OleDbDataAdapter(strSQL, strConn);
OleDbConnection cn = da.SelectCommand.Connection;
OleDbCommand cmdGetIdentity = new OleDbCommand("SELECT
@@IDENTITY", cn);
da.RowUpdated += new
OleDbRowUpdatedEventHandler(HandleRowUpdated);
DataTable tbl = CreateMyDataTable();
da.Fill(tbl);
...
da.Update(tbl);

private void HandleRowUpdated(object sender,
OleDbRowUpdatedEventArgs e)
{
if ((e.Status == UpdateStatus.Continue) &&
((e.StatementType == StatementType.Insert))
{
e.Row["OrderID"] =
Int32.Parse(cmdGetIdentity.ExecuteScalar().ToString());
e.Row.AcceptChanges();
}
}

You can use similar techniques to retrieve server-generated
values from other databases as well. MySQL developers can use
the "LAST_INSERT_ID()" instead of "@@IDENTITY" to retrieve the
last auto-increment value generated. Oracle developers can use
"SELECT SequenceName.CURRVAL FROM DUAL" to retrieve the last
value generated for a sequence on the connection.


3.) How do I cascade the new key values to the child rows before
I submit them?

This is the simplest part of the process. When you create a
DataRelation object, ADO.NET will add a ForeignKeyConstraint
object to make sure that child rows match up to a parent row.
The ForeignKeyConstraint object exposes a UpdateRule property.
If this property is set to Cascade (the default), ADO.NET will
automatically cascade changes made to the parent down to the
associated child rows.

So, if you have a DataRelation set up between the DataTables
based on the auto-increment column, and you've set the parent
DataAdapter's InsertCommand to fetch the new auto-increment
values from the database, ADO.NET will cascade the new values
down to the associated child rows automatically.


I hope this information proves helpful. For more
information, see Chapter 11 of Microsoft ADO.NET, available
through Microsoft Press.
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top