isladogs
MVP / VIP
- Local time
- Today, 14:59
- Joined
- Jan 14, 2017
- Messages
- 18,548
EDIT 15/05/2017: Added additional information & an example database (with MSysObjects errors left in)
The system table MSysObjects keeps a record of all items in a database so these can be used by forms/reports/module code etc
Each item is identified using a type value and a flag value
See attached image - tblSysObjectTypes
Normally the MSysObjects table works very well but things can go wrong leaving incorrect data in the table e.g. if the database crashes for any reason
If errors build up over time, I believe these may eventually make the database unusable.
In other words, don't ignore the problems as they won't go away!
NOTE:
It is important to remember that the MSysObjects table has been made deliberately difficult to edit.
This is to prevent users tampering without realising the potential consequences to their databases
This article discusses 3 types of problem that can occur & a solution for each
1. TMPCLP items
After a database object is deleted, Access keeps a copy on memory until the database is closed.
However, if the database crashes for some reason before that has been done, the code for the object remains in the VBE as something like 'Form_~TMPCLP29151 (see screenshot in zip file).
The object itself is of course no longer available or listed in the nav pane.
The objects are left in the system table MSysObjects but (for safety reasons) this table cannot be directly edited
It is NOT possible to remove such objects using code like:
DoCmd.DeleteObject acForm, "Form_~TMPCLP21541"
Similarly, doing a compact/repair does NOT remove these 'phantom' items.
The 'standard' solution is to create a new database & copying all items across.
The ~TMPCLP items are of course not transferred.
Although this works, it is time consuming if you have a large database
Until recently, I thought there was no way of directly deleting the 'phantom' object code from the VBE.
However, after some experimentation, I came up with 2 successful approaches :
a) Use a recordset to cycle through & delete the ~TMPCLP objects found. This does work!
NOTE: As many of you will already know, the values in the select case statement refer to the object type code from the MSysObjects table
This approach worked perfectly & was very fast.
In a large db of about 5000 objects, 3 TMPCLP objects were found and removed in less than 2 seconds
For some reason, only one of these were shown in the VBE window
b). There is an even easier method if you want to avoid code:
Just replace the 'phantom' object with a real one!
2. Wrongly 'flagged' items
All form & report items containing a row source are assigned their own record in the MSysObjects table
These are identified as TEMP queries (type = 5 ; flag = 3) and the object name will look similar to this:
~sq_c#frmMessageLog~sq_ccboPhone
~sq_cfrmMessageLog~sq_ccboPhone
~sq_cfrmSendEmail~sq_cLstContactEmail
~sq_ffrmPStats3
~sq_rrptPRecordTeacherCrosstab
NOTE: ~sq_f = form ; ~sq_c = form control ; ~sq_r = report ; ~sq_d = report control
Access ignores these 'TEMP queries' in the query designer window
However, recently one of my databases, wrongly re-flagged some items as 'normal queries' - I've no idea why.
As a result, these 'wrongly flagged items appeared in the query designer window (see screenshots in zip file)
I created another routine, similar to the first one, to remove these items
3. 'Extinct' items
I also found a number of items which were still in the MSysObjects table though the objects had already been deleted
I identified these by checking for 'parent' objects no longer in the database.
(see screenshot in zip file)
A third routine was created to deal with these items - this was slightly trickier to manage - but the following does work
-----------------------------------------------------------
Attached is a zip file containing an example database, MSysObjectEditor-WithErrorObjects.accdb including all 3 routines.
I've deliberately left several of each type of error in the db so you can test out the routines for yourself.
There are 30 items in the MSysObjects table of which 17 are errors to be removed.
After running all 3 routines, you will be left with just 13 valid items
I've also included the 4 images - please copy these to the same folder as they are referenced in the database main form
If you wish to use the routines in your own databases, copy the following items:
a) table tblSysObjectTypes
b) all 5 queries starting with qryMSys ...
c) module modDatabaseObjects
d) module modBackupDB (only needed if you want to use my backup routine - CopyCurrentDatabase)
NOTE:
BEFORE running any of these routines, it is STRONGLY recommended that you make a copy of the front-end database - just in case!
I have included a routine CopyCurrentDatabase to do this (or you can use your own version if you prefer - modify the code if so...)
I hope this helps some of you ....
Any comments, questions or issues, please send me a private or visitor message
The system table MSysObjects keeps a record of all items in a database so these can be used by forms/reports/module code etc
Each item is identified using a type value and a flag value
See attached image - tblSysObjectTypes
Normally the MSysObjects table works very well but things can go wrong leaving incorrect data in the table e.g. if the database crashes for any reason
If errors build up over time, I believe these may eventually make the database unusable.
In other words, don't ignore the problems as they won't go away!
NOTE:
It is important to remember that the MSysObjects table has been made deliberately difficult to edit.
This is to prevent users tampering without realising the potential consequences to their databases
This article discusses 3 types of problem that can occur & a solution for each
1. TMPCLP items
After a database object is deleted, Access keeps a copy on memory until the database is closed.
However, if the database crashes for some reason before that has been done, the code for the object remains in the VBE as something like 'Form_~TMPCLP29151 (see screenshot in zip file).
The object itself is of course no longer available or listed in the nav pane.
The objects are left in the system table MSysObjects but (for safety reasons) this table cannot be directly edited
It is NOT possible to remove such objects using code like:
DoCmd.DeleteObject acForm, "Form_~TMPCLP21541"
Similarly, doing a compact/repair does NOT remove these 'phantom' items.
The 'standard' solution is to create a new database & copying all items across.
The ~TMPCLP items are of course not transferred.
Although this works, it is time consuming if you have a large database
Until recently, I thought there was no way of directly deleting the 'phantom' object code from the VBE.
However, after some experimentation, I came up with 2 successful approaches :
a) Use a recordset to cycle through & delete the ~TMPCLP objects found. This does work!
Code:
Sub DeleteTmpClpObjects()
'===============================================
'Purpose : remove any leftover TMPCLP objects from the database
'Author : Colin Riddington - MendipData Systems
'Date : 30/04/2017
'===============================================
'NOTE: an alternative approach that also works is:
'Just replace the 'phantom' object with a real one!
'Create a new form/report with the same name.
'Save it and replace the existing form when prompted
'Close the new form.
'It is automatically deleted along with the TMPCLP item
'===============================================
Dim Rs As DAO.Recordset
Dim strSQL As String
Dim N As Integer
Dim Q As Integer
On Error GoTo Err_Handler
'check for '~TMPCLP' objects
N = DCount("*", "MSysObjects", "MSysObjects.Name Like '~TMPCLP*'")
If N = 0 Then
MsgBox "There are no 'leftover' database objects named '~TMPCLP*" & _
vbNewLine & vbNewLine & _
"This routine will now close", vbInformation, "No TMPCLP objects"
Exit Sub
Else
If MsgBox("There are " & N & " 'leftover' database objects named '~TMPCLP*" & _
vbNewLine & vbNewLine & _
"Click OK to remove these objects from the database", _
vbExclamation + vbOKCancel, "Remove " & N & " TMPCLP objects?") = vbCancel Then Exit Sub
End If
If MsgBox("You should backup the 'front end' database BEFORE deleting these objects" & vbNewLine & vbNewLine & _
"Do a backup now? (RECOMMENDED)", vbExclamation + vbYesNo, "Copy the front end database?") = vbYes Then
CopyCurrentDatabase
End If
strSQL = "SELECT qryMSysObjectsTMPCLP.* FROM qryMSysObjectsTMPCLP;"
Set Rs = CurrentDb.OpenRecordset(strSQL)
Do Until Rs.EOF
Select Case Rs("Type")
Case 1, 4, 6 'tables
DoCmd.DeleteObject acTable, Rs("Name")
Case 5 'queries
DoCmd.DeleteObject acQuery, Rs("Name")
Case -32768 'form
DoCmd.DeleteObject acForm, Rs("Name")
Case -32764 'report
DoCmd.DeleteObject acReport, Rs("Name")
Case -32766
DoCmd.DeleteObject acMacro, Rs("Name")
Case -32761
DoCmd.DeleteObject acModule, Rs("Name")
Case Else
'???
'look at what was printed in the immediate window
'and include the type in the select case
Debug.Print Rs("Type"), Rs("Name")
End Select
Rs.MoveNext
Loop
Rs.Close
Set Rs = Nothing
'check again for '~TMPCLP' objects
Q = DCount("*", "MSysObjects", "MSysObjects.Name Like '~TMPCLP*'")
'end message
If Q = N Then 'none removed
MsgBox "None of the " & N & " 'leftover' database objects named '~TMPCLP*'" & _
" could be removed from the database", vbCritical, "TMPCLP objects were not deleted"
ElseIf Q = 0 Then 'all removed
MsgBox "All " & N & " 'leftover' database objects named '~TMPCLP*'" & _
" have been removed from the database", vbInformation, "TMPCLP objects successfully deleted"
Else: 'partly deleted
MsgBox N - Q & " 'leftover' database objects named '~TMPCLP*'" & _
" have been removed from the database" & vbNewLine & vbNewLine & _
"However, " & Q & " '~TMPCLP' objects were not removed", vbExclamation, "TMPCLP objects partly deleted"
End If
Exit_Handler:
Exit Sub
Err_Handler:
MsgBox "Error " & err.Number & " in DeleteTmpClpObjects procedure :" & vbNewLine & _
" - " & err.Description, vbExclamation, "Error"
Resume Next
End Sub
NOTE: As many of you will already know, the values in the select case statement refer to the object type code from the MSysObjects table
This approach worked perfectly & was very fast.
In a large db of about 5000 objects, 3 TMPCLP objects were found and removed in less than 2 seconds
For some reason, only one of these were shown in the VBE window
b). There is an even easier method if you want to avoid code:
Just replace the 'phantom' object with a real one!
Create a new form/report with the same name.
Save it and replace the existing form when prompted
Close the new form.
It is automatically deleted along with the TMPCLP item
2. Wrongly 'flagged' items
All form & report items containing a row source are assigned their own record in the MSysObjects table
These are identified as TEMP queries (type = 5 ; flag = 3) and the object name will look similar to this:
~sq_c#frmMessageLog~sq_ccboPhone
~sq_cfrmMessageLog~sq_ccboPhone
~sq_cfrmSendEmail~sq_cLstContactEmail
~sq_ffrmPStats3
~sq_rrptPRecordTeacherCrosstab
NOTE: ~sq_f = form ; ~sq_c = form control ; ~sq_r = report ; ~sq_d = report control
Access ignores these 'TEMP queries' in the query designer window
However, recently one of my databases, wrongly re-flagged some items as 'normal queries' - I've no idea why.
As a result, these 'wrongly flagged items appeared in the query designer window (see screenshots in zip file)
I created another routine, similar to the first one, to remove these items
Code:
Sub DeleteMSysErrorObjects()
'===============================================
'Purpose : remove any incorrectly flagged Msys objects from the database
'Author : Colin Riddington - MendipData Systems
'Date : 12/05/2017
'===============================================
Dim Rs As DAO.Recordset
Dim strSQL As String
Dim N As Integer
Dim Q As Integer
On Error GoTo Err_Handler
'check for incorrectly flagged objects
N = DCount("*", "qryMSysObjectsERROR")
If N = 0 Then
MsgBox "There are no 'incorrectly flagged' database objects" & _
vbNewLine & vbNewLine & _
"This routine will now close", vbInformation, "No incorrectly flagged objects"
Exit Sub
Else
If MsgBox("There are " & N & " 'incorrectly flagged' database objects" & _
vbNewLine & vbNewLine & _
"Click OK to remove these objects from the database", _
vbExclamation + vbOKCancel, "Remove " & N & " incorrectly flagged objects?") = vbCancel Then Exit Sub
End If
If MsgBox("You should backup the 'front end' database BEFORE deleting these objects" & vbNewLine & vbNewLine & _
"Do a backup now? (RECOMMENDED)", vbExclamation + vbYesNo, "Copy the front end database?") = vbYes Then
CopyCurrentDatabase
End If
strSQL = "SELECT qryMSysObjectsERROR.* FROM qryMSysObjectsERROR;"
Set Rs = CurrentDb.OpenRecordset(strSQL)
Do Until Rs.EOF
Select Case Rs("Type")
Case 1, 4, 6 'tables
DoCmd.DeleteObject acTable, Rs("Name")
Case 5 'queries
DoCmd.DeleteObject acQuery, Rs("Name")
Case -32768 'form
DoCmd.DeleteObject acForm, Rs("Name")
Case -32764 'report
DoCmd.DeleteObject acReport, Rs("Name")
Case -32766
DoCmd.DeleteObject acMacro, Rs("Name")
Case -32761
DoCmd.DeleteObject acModule, Rs("Name")
Case Else
'???
'look at what was printed in the immediate window
'and include the type in the select case
Debug.Print Rs("Type"), Rs("Name")
End Select
Rs.MoveNext
Loop
Rs.Close
Set Rs = Nothing
'check again for incorrectly flagged objects
Q = DCount("*", "qryMSysObjectsERROR")
'end message
If Q = N Then 'none removed
MsgBox "None of the " & N & " 'incorrectly flagged' database objects'" & _
" could be removed from the database", vbCritical, "Incorrectly flagged objects were not deleted"
ElseIf Q = 0 Then 'all removed
MsgBox "All " & N & " 'incorrectly flagged' database objects" & _
" have been removed from the database", vbInformation, "Incorrectly flagged objects successfully deleted"
Else 'partly deleted
MsgBox N - Q & " 'Incorrectly flagged' database objects" & _
" have been removed from the database" & vbNewLine & vbNewLine & _
"However, " & Q & " 'incorrectly flagged' objects were not removed", vbExclamation, "Incorrectly flagged objects partly deleted"
End If
Exit_Handler:
Exit Sub
Err_Handler:
MsgBox "Error " & err.Number & " in DeleteMSysErrorObjects procedure :" & vbNewLine & _
" - " & err.Description, vbExclamation, "Error"
Resume Next
End Sub
3. 'Extinct' items
I also found a number of items which were still in the MSysObjects table though the objects had already been deleted
I identified these by checking for 'parent' objects no longer in the database.
(see screenshot in zip file)
A third routine was created to deal with these items - this was slightly trickier to manage - but the following does work
Code:
Sub DeleteMSysExtinctObjects()
'===============================================
'Purpose : remove any Msys objects that are no longer in the database
'Author : Colin Riddington - MendipData Systems
'Date : 13/05/2017
'===============================================
Dim Rs As DAO.Recordset
Dim strSQL As String
Dim N As Integer
Dim Q As Integer
On Error GoTo Err_Handler
'check for MSys objects that are 'extinct' (no longer in the database)
N = DCount("*", "qryMSysObjectsEXTINCT")
If N = 0 Then
MsgBox "There are no 'extinct' database objects" & _
vbNewLine & vbNewLine & _
"This routine will now close", vbInformation, "No extinct objects"
Exit Sub
Else
If MsgBox("There are " & N & " 'extinct' database objects" & _
vbNewLine & vbNewLine & _
"Click OK to remove these objects from the database", _
vbExclamation + vbOKCancel, "Remove " & N & " extinct objects?") = vbCancel Then Exit Sub
End If
If MsgBox("You should backup the 'front end' database BEFORE deleting these objects" & vbNewLine & vbNewLine & _
"Do a backup now? (RECOMMENDED)", vbExclamation + vbYesNo, "Copy the front end database?") = vbYes Then
CopyCurrentDatabase
End If
strSQL = "SELECT qryMSysObjectsEXTINCT.* FROM qryMSysObjectsEXTINCT;"
Set Rs = CurrentDb.OpenRecordset(strSQL)
Do Until Rs.EOF
Select Case Rs("Type")
Case 1, 4, 6 'tables
DoCmd.DeleteObject acTable, Rs("Name")
Case 5 'queries
DoCmd.DeleteObject acQuery, Rs("Name")
Case -32768 'form
DoCmd.DeleteObject acForm, Rs("Name")
Case -32764 'report
DoCmd.DeleteObject acReport, Rs("Name")
Case -32766
DoCmd.DeleteObject acMacro, Rs("Name")
Case -32761
DoCmd.DeleteObject acModule, Rs("Name")
Case Else
'???
'look at what was printed in the immediate window
'and include the type in the select case
Debug.Print Rs("Type"), Rs("Name")
End Select
Rs.MoveNext
Loop
Rs.Close
Set Rs = Nothing
'check again for MSys objects that are 'extinct' (no longer in the database)
Q = DCount("*", "qryMSysObjectsEXTINCT")
'end message
If Q = N Then 'none removed
MsgBox "None of the " & N & " 'extinct' database objects'" & _
" could be removed from the database", vbCritical, "Extinct database objects were not deleted"
ElseIf Q = 0 Then 'all removed
MsgBox "All " & N & " 'incorrectly flagged' database objects" & _
" have been removed from the database", vbInformation, "Extinct database objects successfully deleted"
Else 'partly deleted
MsgBox N - Q & " 'extinct' database objects" & _
" have been removed from the database" & vbNewLine & vbNewLine & _
"However, " & Q & " 'extinct' database objects were not removed", _
vbExclamation, "Extinct database objects partly deleted"
End If
Exit_Handler:
Exit Sub
Err_Handler:
' If Err <> 5 And Err <> 3071 And Err <> 2498 Then
MsgBox "Error " & err.Number & " in DeleteMSysEXTINCTObjects procedure :" & vbNewLine & _
" - " & err.Description, vbExclamation, "Error"
' End If
Resume Next
End Sub
-----------------------------------------------------------
Attached is a zip file containing an example database, MSysObjectEditor-WithErrorObjects.accdb including all 3 routines.
I've deliberately left several of each type of error in the db so you can test out the routines for yourself.
There are 30 items in the MSysObjects table of which 17 are errors to be removed.
After running all 3 routines, you will be left with just 13 valid items
I've also included the 4 images - please copy these to the same folder as they are referenced in the database main form
If you wish to use the routines in your own databases, copy the following items:
a) table tblSysObjectTypes
b) all 5 queries starting with qryMSys ...
c) module modDatabaseObjects
d) module modBackupDB (only needed if you want to use my backup routine - CopyCurrentDatabase)
NOTE:
BEFORE running any of these routines, it is STRONGLY recommended that you make a copy of the front-end database - just in case!
I have included a routine CopyCurrentDatabase to do this (or you can use your own version if you prefer - modify the code if so...)
I hope this helps some of you ....
Any comments, questions or issues, please send me a private or visitor message
Attachments
Last edited: