ACC: How to Duplicate Main Form and Its Subform Detail RecordsID: Q132032
|
Moderate: Requires basic macro, coding, and interoperability skills.
The Command Button Wizard provides a Duplicate Record command button that
you can use to duplicate the current record; however, this command button
does not duplicate any detail of the records associated with that record
that may appear in a subform.
This article describes how you can automate the duplication of a main form
record and its associated subform detail records. The article shows you how
to add a command button to the Orders form of the sample database
Northwind.mdb (or NWIND.MDB in version 2.0) that duplicates the current
order into a new order. The article then shows you how to use the new
command button.
In order to duplicate a main form record and its associated subform detail
records, the following process must be automated:
Name: btnDuplicate
Caption: Duplicate
OnClick: [Event Procedure]
Private Sub btnDuplicate_Click ()
Dim dbs As Database, Rst As Recordset
Dim F As Form
' Return Database variable pointing to current database.
Set dbs = CurrentDb
Set Rst = Me.RecordsetClone
On Error GoTo Err_btnDuplicate_Click
' Tag property to be used later by the append query.
Me.Tag = Me![OrderID]
' Add new record to end of Recordset object.
With Rst
.AddNew
!CustomerID = Me!CustomerID
!EmployeeID = Me!EmployeeID
!OrderDate = Me!OrderDate
!RequiredDate = Me!RequiredDate
!ShippedDate = Me!ShippedDate
!ShipVia = Me!ShipVia
!Freight = Me!Freight
!ShipName = Me!ShipName
!ShipAddress = Me!ShipAddress
!ShipCity = Me!ShipCity
!ShipRegion = Me!ShipRegion
!ShipPostalCode = Me!ShipPostalCode
!ShipCountry = Me!ShipCountry
.Update ' Save changes.
.Move 0, .LastModified
End With
Me.Bookmark = Rst.Bookmark
' Run the Duplicate Order Details append query which selects all
' detail records that have the OrderID stored in the form's
' Tag property and appends them back to the detail table with
' the OrderID of the duplicated main form record.
DoCmd.SetWarnings False
DoCmd.OpenQuery "Duplicate Order Details"
DoCmd.SetWarnings True
'Requery the subform to display the newly appended records.
Me![Orders Subform].Requery
Exit_btnduplicate_Click:
Exit Sub
Err_btnDuplicate_Click:
MsgBox Error$
Resume Exit_btnduplicate_Click:
End Sub
Sub btnDuplicate_Click ()
Dim Msg As String
Dim NewOrderID As Variant
Dim Criteria As String
' Trap any unexpected error that may occur.
On Error GoTo Err_btnDuplicate_Click
' Prompt for a unique Order ID number.
While NewOrderID = ""
Msg = "Enter a unique Order ID for the duplicated record"
NewOrderID = InputBox(Msg)
' If the user pressed Cancel, then exit sub.
If NewOrderID = "" Then Exit Sub
' Make sure the number has not been used yet.
Criteria = "[Order ID]=" & NewOrderID
If Not IsNull(DLookup("[Order ID]", "Orders", Criteria)) Then
MsgBox "The specified Order ID already exists!"
NewOrderID = ""
End If
Wend
' Record the current Order ID (primary key value) into the
' form's Tag property to be used latter by the append query.
Me.Tag = Me![Order ID]
' Duplicate the current main form record:
' Select Record, Copy Record, Paste Append Record.
DoCmd DoMenuItem A_FORMBAR, A_EDITMENU, _
A_SELECTRECORD_V2, , A_MENU_VER20
DoCmd DoMenuItem A_FORMBAR, A_EDITMENU, A_COPY, , A_MENU_VER20
DoCmd DoMenuItem A_FORMBAR, A_EDITMENU, 6, , A_MENU_VER20
' Insert the new Order ID into the duplicated main form record.
Me![Order ID] = NewOrderID
' Save the duplicated main form record.
DoCmd DoMenuItem A_FORMBAR, A_FILE, A_SAVERECORD, , A_MENU_VER20
' Run the Duplicate Order Details append query which selects all
' detail records that have the Order ID stored in the form's
' Tag property and appends them back to the detail table with
' the Order ID of the duplicated main form record.
DoCmd SetWarnings False
DoCmd OpenQuery "Duplicate Order Details"
DoCmd SetWarnings True
' Requery the subform to display the newly appended records.
Me![Orders Subform].Requery
Exit_btnDuplicate_Click:
Exit Sub
Err_btnDuplicate_Click:
MsgBox Error$
Resume Exit_btnDuplicate_Click:
End Sub
Microsoft "Getting Results with Microsoft Office 97," Part 17, Page 649,
"Automate Repetitive Tasks in Microsoft Access"
Keywords : kbusage FmsHowto
Version : 2.0 7.0 97
Platform : WINDOWS
Issue type : kbhowto
Last Reviewed: April 20, 1999