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 7 and 2 and type the answer here:
  • Post
  • PingBack from http://www.anith.com/?p=37999

  • I’ve posted before about how to use TableAdapters to update parent-child (master-detail) relationships

  • Hi Beth, I'm confused, are the DataSet designer and Data Sources window available in Access?

  • Hi grovelli,

    Sorry I wasn't clear. You can use *Visual Studio* to connect to Access databases throgh the ADO.NET OleDb client classes. Design your database in Access then use Visual Studio to design the application and use the DataSet designer and Data Sources window in VS to connect to the Access database file.

    A scenario where this is appropriate is if you are migrating to .NET from Access or VB6 and need to keep the data in Access or if you are creating small business applications. Access databases are multi-user file-based databases so they can't scale or give you the security like SQL Server but a lot of small businesses use them.

    However for new .NET development I'd suggest using SQL Compact instead (if your application is single-user) or using the free SQL Express version (if you need multi-user). You get more capibilities and SQL integrates better with Visual Studio.

    HTH,

    -B

  • Try as they might, they will never be able to replace Access for its unrivalled flexibility, topflight reporting engine with pivot tables and pivot charts, tight interface with the rest of the Office suite... ;-)

  • Do you think the lack of the code found in this blog is the reason why I keep getting the error "Cannot clear table tblPhone because ForeignKeyConstraint tblPhonetblConsignee enforces constraints and there are child rows in table tblConsignee" every time I delete a parent record (one that is not linked to a child) and then try to re-fill the table adapters? (I am using an Access Database that does not use cascading for deletion, but makes sure that a parent record cannot be deleted if it is linked to a child).

  • Hi Andrew,

    It sounds like you still have abandoned child rows. Make sure when you refill, that you fill the parent table first and then the child table.

    I'd also try setting the cascade on Updates and Deletes on the DataSet relation (like I show above in the dataset designer).

    If that doesn't work you may also want to try setting EnforceConstraints on the dataset to False while you are refilling the tables and then set back to True again after the fill. If it fails when you try to re-enable the constraints, look at the data in the dataset and you should see the abandoned child rows. This would mean that you probably need to adjust your TableAdapter query.

    HTH,

    -B

  • Worked perfectly.  You are awesome!  Thank you!

  • Thanks, my mom thinks so too ;-) Glad you got it working!

  • At the part

    Enhancing the TableAdapter Partial Classes you say: "Right-click on the TableAdapter and select View Code and the partial class file that you can edit will be created for you"

    I did this on the table icons which are at the bottom of the Form1.vb [Design] tab but it only shows me the existing main form code (without these partial classes).

    Do you have any idea why this is happening?

  • Hi Kostas,

    You need to right-click on the TableAdapter *class definition* not the instance on the form. Open the DataSet designer (double-click on the dataset.xsd in the Solution Explorer).

    HTH,

    -B

  • Thank you very much, for your answer Beth,

    by right-click on the dataset.xsd in the Solution Explorer and select View code the dataset.vb file shows but it's empty. I typped your code and now the primary key is updated from the database.

    of cource your way is simpler,

    Thanx again...

  • Thank you Beth for explaining this.

    Do you happen to have a C# version of the code?

    Mike

  • Hi Beth,

    I get here by google search. I'm working with MS Access Database 2003 and VS 2005.

    When I do: "Right-click on the TableAdapter class in the DataSet Designer and select View Code", the partial class file created does not looks like you post it. I even can't see its namespace.

    It shows the Dataset Partial class instead of TableAdapter Partial class, and the partial class for the tables too. That's what it shows.

    How can I get the TableAdapter partical class?

    Can I overwrite the partial class created by default, and paste what you post (namespace and tableadapter partial classes)?

    I would like VB do it by itself as you said.

    I have tried many times many ways with no results

    I appreciate yuor help

    Regards,

    Cesar

  • Hi Cesar,

    Did you right-click on the TableAdapter or the DataSet? You can also double-click on the TableAdapter name (under the dataset). You can also just copy the code into the partial class file I have above, including the tableadapter namespace.

    HTH,

    -B

Page 1 of 5 (63 items) 12345