ted.martin
Registered User.
- Local time
- Today, 02:30
- Joined
- Sep 24, 2004
- Messages
- 743
Given the amount of research and then trial and error, I thought I would post my soloution to what has been a tricky problem. No website gave me the simple answer or at least an answer that would actually run. Anyway here is the background.
One table has (say) 6 separate records all with a same Project Reference field. There is also a multi-value field too.
What I wanted to do was copy the records from one Project Reference to another in the same table. Sounds simple but needed to not only cope with the multi-value field but also change the Project Reference value to the new one.
Here is is:
Set rstFrom = dbs.OpenRecordset("SELECT [Risk Assessment and Area Classification].* FROM [Risk Assessment and Area Classification] " & _
"WHERE ((([Risk Assessment and Area Classification].ProjectRef)= '" & targetProjectRef & "'))" & _
"ORDER BY [Risk Assessment and Area Classification].[Installation ID]", dbOpenSnapshot)
Set rstTo = dbs.OpenRecordset("Risk Assessment and Area Classification", dbOpenDynaset)
rstFrom.MoveFirst
Do Until rstFrom.EOF
rstTo.AddNew
For iFor = 1 To rstFrom.Fields.Count - 1 ' use 1 not 0 as has ID field is Autonumber
If rstFrom.Fields(iFor).Type <> 104 And rstFrom.Fields(iFor).Type <> 109 Then ' types 104 and 109 are Multi-Value field
If rstTo.Fields(iFor).Name = "ProjectRef" Then
rstTo.Fields(iFor).Value = myProjectRef
Else
rstTo.Fields(iFor).Value = rstFrom.Fields(iFor).Value
End If
Else
Set rstMVFrom = rstFrom.Fields(iFor).Value
If rstMVFrom.RecordCount > 0 Then
Set rstMVTo = rstTo.Fields(iFor).Value
Do While rstMVFrom.EOF = False
rstMVTo.AddNew
rstMVTo.Fields(0).Value = rstMVFrom.Fields(0).Value
rstMVTo.Update
rstMVFrom.MoveNext
Loop
rstMVFrom.Close
rstMVTo.Close
End If ' rstFrom
End If ' iFor
Next iFor
rstTo.Update
rstFrom.MoveNext
Loop ' rstFrom
rst2.Close
Set rst2 = Nothing
Hope this helps someone.
One table has (say) 6 separate records all with a same Project Reference field. There is also a multi-value field too.
What I wanted to do was copy the records from one Project Reference to another in the same table. Sounds simple but needed to not only cope with the multi-value field but also change the Project Reference value to the new one.
Here is is:
Set rstFrom = dbs.OpenRecordset("SELECT [Risk Assessment and Area Classification].* FROM [Risk Assessment and Area Classification] " & _
"WHERE ((([Risk Assessment and Area Classification].ProjectRef)= '" & targetProjectRef & "'))" & _
"ORDER BY [Risk Assessment and Area Classification].[Installation ID]", dbOpenSnapshot)
Set rstTo = dbs.OpenRecordset("Risk Assessment and Area Classification", dbOpenDynaset)
rstFrom.MoveFirst
Do Until rstFrom.EOF
rstTo.AddNew
For iFor = 1 To rstFrom.Fields.Count - 1 ' use 1 not 0 as has ID field is Autonumber
If rstFrom.Fields(iFor).Type <> 104 And rstFrom.Fields(iFor).Type <> 109 Then ' types 104 and 109 are Multi-Value field
If rstTo.Fields(iFor).Name = "ProjectRef" Then
rstTo.Fields(iFor).Value = myProjectRef
Else
rstTo.Fields(iFor).Value = rstFrom.Fields(iFor).Value
End If
Else
Set rstMVFrom = rstFrom.Fields(iFor).Value
If rstMVFrom.RecordCount > 0 Then
Set rstMVTo = rstTo.Fields(iFor).Value
Do While rstMVFrom.EOF = False
rstMVTo.AddNew
rstMVTo.Fields(0).Value = rstMVFrom.Fields(0).Value
rstMVTo.Update
rstMVFrom.MoveNext
Loop
rstMVFrom.Close
rstMVTo.Close
End If ' rstFrom
End If ' iFor
Next iFor
rstTo.Update
rstFrom.MoveNext
Loop ' rstFrom
rst2.Close
Set rst2 = Nothing
Hope this helps someone.