Using TableAdapters to Insert Related Data into an MS Access Database

Using TableAdapters to Insert Related Data into an MS Access Database

Rate This
  • Comments 63

I’ve posted before about how to use TableAdapters to update parent-child (master-detail) relationships against SQL server. It’s pretty straightforward and Visual Studio generates all the code for you to properly insert, update and delete your data. However if you’re using MS Access then there’s one thing that Visual Studio doesn’t do because it’s not supported when using Access.

How Parent-Child Inserts Work

When Visual Studio generates the insert commands on a SQL-Server TableAdapter it looks to see if the table’s primary keys are auto-generated (identity columns) and if so, Visual Studio will write an additional statement to retrieve the key using the SCOPE_IDENTITY functionality of SQL Server. When in the DataSet designer, if you look at the insert statement in the properties window for the SQLTableAdapter you will see two statements separated by a semi-colon:

image

INSERT INTO [dbo].[Products] ([ProductName], [SupplierID], [CategoryID], [QuantityPerUnit], [UnitPrice], [UnitsInStock], [UnitsOnOrder], [ReorderLevel], [Discontinued]) VALUES (@ProductName, @SupplierID, @CategoryID, @QuantityPerUnit, @UnitPrice, @UnitsInStock, @UnitsOnOrder, @ReorderLevel, @Discontinued);
SELECT ProductID, ProductName, SupplierID, CategoryID, QuantityPerUnit, UnitPrice, UnitsInStock, UnitsOnOrder, ReorderLevel, Discontinued FROM Products WHERE (ProductID = SCOPE_IDENTITY())

SQL Server supports batch statements through ADO.NET commands so this will populate the primary key back in the DataRow inside the DataSet as each row is inserted into the database. If you are enforcing foreign key constraints with a parent-child relation set up on two DataTables and you set the Update Rule to Cascade then any foreign key references will also be updated in the children. Because the TableAdapterManager will save the children after their parent records, when the child saves to the database it will contain the correct parent key which must already exist in the database before a child can be inserted in order to maintain referential integrity in the database.

Unfortunately Access doesn’t support batch statements. If you look at what is generated for Access you will only see one statement (also the OLEDB provider does not support named parameters hence the question mark placeholders):

INSERT INTO `Products` (`ProductName`, `SupplierID`, `CategoryID`, `QuantityPerUnit`, `UnitPrice`, `UnitsInStock`, `UnitsOnOrder`, `ReorderLevel`, `Discontinued`) VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?)

So if you are doing inserts, especially for related parent-child data, you need a way to intercept the DataRow and set the primary key right after the row is inserted into the database and before any children are inserted. There’s an excellent article by Bill Vaughn (VB MVP) that explains this issue as well as a KB Article that shows how to solve it using the DataAdapter. These were written before Visual Studio had the concept of TableAdapters (which were added in VS 2008) so let’s see how we could use this technique to enhance our TableAdapters via partial classes.

Setting up the Parent-Child DataSet

The first step is to make sure you set up the tables in your Access database to use the AutoNumber feature for the primary keys on the rows. Here I’m using Access 2007 against the Northwind Access database. AutoNumber is used for both the primary keys on the Products and Categories tables:

image

Next you need to make sure you set up the relationship on the DataSet properly so that the primary key on the parent will cascade to the foreign key on the child. Set the relation in the DataSet designer to "Both Relation and Foreign Key Constraint" and then set the Update and Delete rules to Cascade. Just right-click on the relation and select "Edit Relation" in the DataSet designer:

image image

Loading and Editing the Parent-Child DataSet

You now are telling the DataSet to enforce the foreign key relationship which means that you must have a parent for every child. This means you have to load the data in parent then child order. You also have to be careful with your queries. You have to make sure that every row in the child DataTable will have a corresponding parent row in the parent DataTable. This also means that you have to make sure to call EndEdit on any new parent BindingSource before any children can be added.

For example, from the Data Sources window drag the Categories parent table as details and the related child Products table as a DataGridView on the form and Visual Studio will generate the code to load and save our data.

image

Head over to the code behind and make sure that the parent is filled first before the child. Also make sure that EndEdit is called on the CategoriesBindingSource before a new product can be inserted into the DataGridView. EndEdit will flush the data row being edited by the controls into the DataTable. In this example I just am calling EndEdit on the CategoriesBindingSource when the user selects the grid.

Public Class Form1

    Private Sub CategoriesBindingNavigatorSaveItem_Click() _
            Handles CategoriesBindingNavigatorSaveItem.Click
        Me.Validate()
        'Call EndEdit on all BindingSources! 
        Me.CategoriesBindingSource.EndEdit()
        Me.ProductsBindingSource.EndEdit()
        Me.TableAdapterManager.UpdateAll(Me.ProductsDataSet)
    End Sub

    Private Sub Form1_Load() Handles MyBase.Load
        'Load parent before child!
        Me.CategoriesTableAdapter.Fill(Me.ProductsDataSet.Categories)
        Me.ProductsTableAdapter.Fill(Me.ProductsDataSet.Products)
    End Sub

    Private Sub ProductsDataGridView_Enter() Handles ProductsDataGridView.Enter
        'You must commit the parent row to the DataTable before adding child rows 
        Me.CategoriesBindingSource.EndEdit()
    End Sub

End Class

Note that anytime you call EndEdit and flush the data to the DataTable, the row must not fail any constraints either (i.e. if NULLs aren’t being allowed then you have to set those values). One way to handle this is to add code to set default values in the TableNewRow handler on the DataTable.

Enhancing the TableAdapter Partial Classes

 

 

 

Now for the good stuff. Like I mentioned in the beginning, you need a way to set the primary key on the parent right after the row is inserted into the database and before any children are inserted. Now that we have keys cascading we just need to write code to handle the RowUpdated event on the DataAdapter inside the TableAdapter partial class. TableAdapters are generated classes that Visual Studio creates for us from the DataSet designer. These classes are declared as Partial Classes so that means we can add code to the same class even if it’s in a separate file. Right-click on the TableAdapter class in the DataSet Designer and select View Code and the partial class file that you can edit will be created for you.

Namespace ProductsDataSetTableAdapters

    Partial Public Class CategoriesTableAdapter

    End Class

    Partial Public Class ProductsTableAdapter

    End Class
End Namespace

In these classes we can handle the RowUpdated event on the private variable _adapter which gives us access to the ADO.NET DataAdapter that is executing the updates to our rows. The way we retrieve the primary key is by executing the statement  SELECT @@IDENTITY which tells Access to send back the last primary key it used on the connection. Because you have to add this handler to all your TableAdapters that are working against MS Access, to make things more manageable you can create a class with a Shared (static) method to handle setting the key and then call that from the handlers.

Imports System.Data.OleDb

Public Class AccessIDHelper
    ''' <summary>
    ''' Retrieves the primary key autonumber values from Access
    ''' </summary>
    ''' <remarks></remarks>
    Public Shared Sub SetPrimaryKey(ByVal trans As OleDbTransaction, _
                                    ByVal e As OleDbRowUpdatedEventArgs)
        If e.Status = UpdateStatus.Continue AndAlso _
           e.StatementType = StatementType.Insert Then
            ' If this is an INSERT operation...
            Dim pk = e.Row.Table.PrimaryKey
            ' and a primary key column exists...
            If pk IsNot Nothing AndAlso pk.Count = 1 Then
                Dim cmdGetIdentity As New OleDbCommand("SELECT @@IDENTITY", trans.Connection, trans)
                ' Execute the post-update query to fetch new @@Identity
                e.Row(pk(0)) = CInt(cmdGetIdentity.ExecuteScalar)
                e.Row.AcceptChanges()
            End If
        End If
    End Sub
End Class

Namespace ProductsDataSetTableAdapters

    Partial Public Class CategoriesTableAdapter

        Private Sub _adapter_RowUpdated(ByVal sender As Object, _
                                        ByVal e As System.Data.OleDb.OleDbRowUpdatedEventArgs) _
                                        Handles _adapter.RowUpdated

            AccessIDHelper.SetPrimaryKey(Me.Transaction, e)
        End Sub
    End Class

    Partial Public Class ProductsTableAdapter

        Private Sub _adapter_RowUpdated(ByVal sender As Object, _
                                        ByVal e As System.Data.OleDb.OleDbRowUpdatedEventArgs) _
                                        Handles _adapter.RowUpdated

            AccessIDHelper.SetPrimaryKey(Me.Transaction, e)
        End Sub
    End Class
End Namespace

So that’s how you can get the primary keys into the data rows and have them properly cascaded to the child rows. So now when the children are updated they will have the correct foreign key and the parent will exist in the database. I hope this helps clear up how to work with Access and Visual Studio. 

I’ve posted this example on CodeGallery so have a look.

Enjoy!

Leave a Comment
  • Please add 6 and 7 and type the answer here:
  • Post
  • Hi Beth!,

    Nice to have you response!

    In the DataSet Designer, I select the table then I right-click on the TableAdapter, Which is beneath the list of columns name of the table, and finally select View code.

    My main question is how can I get the TableAdapter Class code?

    I appreciate you help.

    Regards,

  • Try double-clicking on the TableAdapter. I have a feeling you aren't selecting it first.

  • Thanks Beth, I'll try it later and carefully bacuase I still have the same problem.

    I appreciate your time.

    Regards,

    Cesar.

  • No problem, Cesar. You can also just copy the code (including the namespace) directly into the partial class file.

  • Beth,

    I just realize that i don't have the "TableAdapterManager" that appears in your form.

    I also have the problem with "If pk IsNot Nothing AndAlso pk.Count = 1 Then" sentence. The propery count does not appear. And  with "AccessIDHelper.SetPrimaryKey(Me.Transaction, e)". The Transaccion propery/method does not appear too.

    Do you think the TableAdapterManager  would be the problem?

    How do i get it in my form?

    Thanks inadvance for your help

    Regards,

  • Few minutes ago I send you a question, but just in case, here it its again

    Reviewing and doing all againg I have the following:

    I see a "TablaAdapterManager" in your form picture, which is not in mine.How do I get it? It is something wrong I'm missing?

    My "pk" does not have the "Count" Property. It shows others. What do I have to check?

    In the line: "AccessIDHelper.SetPrimaryKey(Me.Transaction, e)" the  "Me" does not have "Transaction" property. Again, what do I have to check?

    I allways appreciate yours Anwers.

    Regards,

  • Hi Cesar,

    You need to be running Visual Studio 2008 (or Express) to see the TableAdapterManager. I'm also taking adantage of type inference in 2008 which automatically infers the type of the DataColumn array. You could also declare the line:

    Dim pk As DataColumn() = ....

  • Hi Beth!

    Many thanks for your answers.

    I' try to move on the next version of VS. In the mid time 'I'll try to figure out how to do it with I have.

    Again, many thanks for you time,

    Cesar

  • Hi really nice explanation.

    I have the same question like Mike before. How we can do this in C#?

    thanks

    Senol

  • Hi Senol,

    The technique is the same in C#. Just add an event handler to the DataAdapter's RowUpdated event to execute the additional command to retrieve the key.

    HTH,

    -B

  • In C#, where can you hook up the event handler in the partial class?  Don't you need to do that within a method?

    Thanks,

    -e

  • Hi Eric,

    Because C# doesn't have declarative event handlers, you need to manually add an event handler in the EndInit method. See this walkthrough for more information:

    http://msdn.microsoft.com/en-us/library/ms171930.aspx

    HTH,

    -B

  • OK, so I tried looking for a virtual or partial method in the generated TableAdapter class that I could use to do the event hookup.  It doesn't look like there is one.  (Were TableAdapters a product of the VB team?  Certainly this blog is the best documentation that exists.)

    Anyway, I gave it up and just created new methods which must be explicitly called from elsewhere in the application.  Here is the result in C# (which is still giving me problems... see below):

    namespace WpfTest.RfpsTableAdapters {

           public partial class RfpsTableAdapter

           {

               public void HookUpEvents()

               {

                   this._adapter.RowUpdated += new OleDbRowUpdatedEventHandler(_adapter_RowUpdated);

               }

               private void _adapter_RowUpdated(object sender, OleDbRowUpdatedEventArgs e)

               {

                   AccessIDHelper.SetPrimaryKey(this.Transaction, e);

               }

           }

           public partial class ChargesTableAdapter

           {

               public void HookUpEvents()

               {

                   this._adapter.RowUpdated += new OleDbRowUpdatedEventHandler(_adapter_RowUpdated);

               }

               private void _adapter_RowUpdated(object sender, OleDbRowUpdatedEventArgs e)

               {

                   AccessIDHelper.SetPrimaryKey(this.Transaction, e);

               }

           }

       public class AccessIDHelper

       {

           public static void SetPrimaryKey(OleDbTransaction trans, OleDbRowUpdatedEventArgs e)

           {

               if ((e.Status == System.Data.UpdateStatus.Continue) && (e.StatementType == System.Data.StatementType.Insert))

               {

                   System.Data.DataColumn[] pk = e.Row.Table.PrimaryKey;

                   if ((pk != null) && (pk.Length == 1))

                   {

                       OleDbCommand cmdGetIdentity = new OleDbCommand("SELECT @@IDENTITY", trans.Connection, trans);

                       e.Row[pk[0]] = (int)(cmdGetIdentity.ExecuteScalar());

                       e.Row.AcceptChanges();

                   }

               }

           }

       }

    }

    It compiles, but now I'm getting a NullReferenceException because this.Transaction is null.  Not sure why yet...

  • Oops, it looks like we were typing simultaneously.  Thanks for the fast reply.

    Thanks to that link, I see what I was missing (and will now share so that no one else has to slap their forehead with so much vigor)... there is no EndInit() method in the generated code, but it *is* present on System.Data.DataSet, so you can just override it.

    I'll repost a clean version of the code above once I make sure it works.

  • Hi Eric,

    Actually for the TableAdapter you should be able to just write a constructor in your partial class that does the event handler hookup. Have you tried that already?

    -B

Page 2 of 5 (63 items) 12345