The combo box control has a nifty event called NotInList. If the LimitToList property of my combo box is set to Yes, and I type a value that is not in the drop-down list, the NotInList event will fire. This will allow me to capture this event and add some programming to it.
Before I go further, I should explain that a combo box can have its drop-down list (the RowSource property) filled by a query, a field list or a value list. The scenario I'm addressing here is a the row source filled by a query from a separate look-up table.
So suppose I have a form where I want to fill in Employee information including what Training they've had. There's a combo box on the form called cboTraining that is filled from a table called tbxTraining that lists the available training opportunities (Word, Excel, etc.). Now suppose further that an employee takes a new type of training that is not already in the training table, say Access. Since I have LimitToList set to Yes, I can't just type "Access" into the training field. I have to select an item in the list. But I also don't want my data entry person to have to stop what they're doing, open the tbxTraining table, add the value, then go back to entering data.
This is where the NotInList event comes in. I can programmatically add the value to my tbxTraining table, refresh the combo box, and the data entry person can just continue on.
To add code to the combo's NotInList event, I open the form in design view and open the the property sheet of the combo box. In the NotInList event, choose [Event Procedure] in the drop-down list. The VBA editor will open with the first and last line of the subroutine already created. Something like this:
Private Sub cboTraining_NotInList(NewData As String, Response As Integer)
End Sub
What I'm going to discuss now is the code that goes between those two lines.
There are a number of different ways to implement adding a value to the drop-down list. Some are easier but dangerous. Others are harder to implement, but safer.
The easiest thing for me to do is to just automatically add a new value to my lookup table when a new type of training is added to the transaction table. To do this, I would add something like the following to my NotInList event of my combo box:
Private Sub cboTraining_NotInList(NewData As String, Response As Integer)
Dim strsql As String
MsgBox "Training type does not exist. Creating new Record in Training table."
strsql = "Insert Into [tbxTraining] ([Training]) values ('" & NewData & "')"
CurrentDb.Execute strsql, dbFailOnError
Response = acDataErrAdded
End Sub
You do want to be a little careful about allowing this depending on the data entry people. It's possible to get multiples of training with slight variations. For instance, a data entry person could add "Access" or "Access Database" to the training table, both of which would refer to the same type of training. I'm not saying this shouldn't be implemented, but you do need to be careful how you do it.
A little safer is to ask the user if they want to add it. That requires only a slight variation:
Private Sub cboTraining_NotInList(NewData As String, Response As Integer)
Dim strsql As String, x As Integer
x = MsgBox("Do you want to add this value to the list?", vbYesNo)
If x = vbYes Then
strsql = "Insert Into [tbxTraining] ([Training]) values ('" & NewData & "')"
CurrentDb.Execute strsql, dbFailOnError
Response = acDataErrAdded
Else
Response = acDataErrContinue
End If
End Sub
This can still give me logical duplicates if my user isn't careful. (Sometimes they'll just say "yes" without ever thinking about it, which is just as bad as the first option).
Another way that is even safer is to programmatically open the maintenance form (say, frmTraining) when the user types a value that isn't in the list, allow them to add the record manually, then save and return to the record in the transaction form.
Private Sub cboTraining_NotInList(NewData As String, Response As Integer)
Dim strsql As String, x As Integer
x = MsgBox("Do you want to add this value to the list?", vbYesNo)
If x = vbYes Then
DoCmd.OpenForm "frmTraining"
Response = acDataErrAdded
Else
Response = acDataErrContinue
End If
End Sub
There are other variations on this theme. On my website, I have a small sample database called NotInList.mdb which illustrates these and other options.
.
Wednesday, July 28, 2010
Tuesday, July 20, 2010
Access 2010: Unrecognized Database Format
I've been seeing more and more people having problems with the Unrecognized Database Format when creating or modifying an Access 2007 (accdb) format database in Access 2010 and then trying to open it again in Access 2007.
The issue appears to be that Access 2010 does not have its own file format. When you add a feature that is specific to A2010 (like the navigation control, data macro, or calculated column), that file becomes forever unreadable to A2007, even if the new feature(s) are removed. The solution appears to be:
I'm told that it is also possible to make the original file A2007 readable by removing the A2010 features and then making a minor edit to the file in a Hex editor. But I'd be wary of that approach. Importing the objects to a new database is safer, more reliable, and frankly simpler.
The issue appears to be that Access 2010 does not have its own file format. When you add a feature that is specific to A2010 (like the navigation control, data macro, or calculated column), that file becomes forever unreadable to A2007, even if the new feature(s) are removed. The solution appears to be:
- Remove all the new features from the file in A2010
- Create a new, blank accdb format database in A2010
- Import all the objects from the old database to the new.
I'm told that it is also possible to make the original file A2007 readable by removing the A2010 features and then making a minor edit to the file in a Hex editor. But I'd be wary of that approach. Importing the objects to a new database is safer, more reliable, and frankly simpler.
Monday, July 19, 2010
New Sample: Form_TreeView_BOM
Form_TreeView_BOM
by A.D. Tejpal
This sample db demonstrates extraction of complete hierarchical chain of sub-assemblies and components for the selected item. The user can select the desired item either by selection via combo box or by using the navigation buttons on the master subform at top left, bound to the master table T_PartMaster. Fields PartName and UnitPrice are available for user interaction (i.e. editing or new entry). UnitPrice is to be entered only for base parts (items which are not meant to have any child assemblies or components)
For the selected item, complete hierarchical chain of sub-assemblies and components gets displayed in the lower subform at right. For base parts, total quantity as well as total price are also shown in respective columns. Summary information (like maximum nesting levels, number of distinct assemblies and base parts as well as total cost of base parts needed for the selected item) gets depicted in label caption at top of this subform. For convenient analysis, the user can select any of the following styles of display, via option group below this subform:
(a) All parts (Complete hierarchical chain).
(b) Assemblies only - arranged as per relevant nesting level.
(c) Assemblies only - Straight.
(d) Base parts only - arranged as per relevant nesting level.
(e) Base parts only - Straight.
Simultaneously, the hierarchical chain of sub-assemblies and components gets depicted as tree view. Total cost of base parts (i.e. items which have no child assemblies or components) also gets depicted at bottom of tree view. Contents of tree view remain in step with the latest selection (out of five listed above) in option group.
Also, there is two way synchronization between tree view and the lower subform at right. If the user selects any node in tree view, corresponding record in subform becomes the current record. Conversely, if the user navigates to any record in the subform, corresponding node in tree view assumes selected state. PartID of matching record in the subform gets highlighted in a manner similar to the shade signifying selected node in treeview.
As the user navigates through master subform at top left, the contents of tree view as well as the two subforms at right keep getting updated as per current selection (treating current PartID on master subform as the top item for which hierarchical chain is to be extracted).
You can find the sample here: http://www.rogersaccesslibrary.com/forum/topic545_post557.html#557
.
by A.D. Tejpal
This sample db demonstrates extraction of complete hierarchical chain of sub-assemblies and components for the selected item. The user can select the desired item either by selection via combo box or by using the navigation buttons on the master subform at top left, bound to the master table T_PartMaster. Fields PartName and UnitPrice are available for user interaction (i.e. editing or new entry). UnitPrice is to be entered only for base parts (items which are not meant to have any child assemblies or components)
For the selected item, complete hierarchical chain of sub-assemblies and components gets displayed in the lower subform at right. For base parts, total quantity as well as total price are also shown in respective columns. Summary information (like maximum nesting levels, number of distinct assemblies and base parts as well as total cost of base parts needed for the selected item) gets depicted in label caption at top of this subform. For convenient analysis, the user can select any of the following styles of display, via option group below this subform:
(a) All parts (Complete hierarchical chain).
(b) Assemblies only - arranged as per relevant nesting level.
(c) Assemblies only - Straight.
(d) Base parts only - arranged as per relevant nesting level.
(e) Base parts only - Straight.
Simultaneously, the hierarchical chain of sub-assemblies and components gets depicted as tree view. Total cost of base parts (i.e. items which have no child assemblies or components) also gets depicted at bottom of tree view. Contents of tree view remain in step with the latest selection (out of five listed above) in option group.
Also, there is two way synchronization between tree view and the lower subform at right. If the user selects any node in tree view, corresponding record in subform becomes the current record. Conversely, if the user navigates to any record in the subform, corresponding node in tree view assumes selected state. PartID of matching record in the subform gets highlighted in a manner similar to the shade signifying selected node in treeview.
As the user navigates through master subform at top left, the contents of tree view as well as the two subforms at right keep getting updated as per current selection (treating current PartID on master subform as the top item for which hierarchical chain is to be extracted).
You can find the sample here: http://www.rogersaccesslibrary.com/forum/topic545_post557.html#557
.
Subscribe to:
Posts (Atom)