Page 1 of 2 12 LastLast
Results 1 to 15 of 20
  1. #1
    MikF is offline Novice
    Windows 11 Access 2010 64bit
    Join Date
    Dec 2023
    Posts
    8

    NotInList no longer working

    Hello,
    I’ve had the following for years, linked together by Primary Key ID fields ..
    tblCities / frmCities
    tblStates / frmStates
    tblMetros / frmMetros
    tblCountries /frmCountries

    Referring to Cities and Metros --- in frmCities, when I click an “AddNewCity” button, it opens up a blank record and allows me to add the new city name.

    Tabbing thru the fields, if I type a new Metro name [that is not currently in the Metros table], a dialog box opens and asks “Do you wish to add “NewMetro” to the list of Markets / Metro Areas …?”
    What used to happen is it would open frmMetros, add a new record with “NewMetro” in that field, ask if I wanted to save it – yes – and close. “NewMetro” would then be added into the Metros table and properly placed in its relevant field in frmCities.

    It worked perfectly for years, haven’t looked under the hood ever since. But am needing to use it again quite frequently. What happens now is ..

    ‘Error 3078’

    The Microsoft Access database engine cannot find the input table or query “Markets”. Make sure it exists and its name is spelled correctly.

    Upon hitting debug, the following code appears, with Set rstMarkets = dbsSmr.OpenRecordset("Markets") in yellow-shading, obviously the issue.
    Don’t believe I’ve changed anything in years.
    Can anyone there please direct me to the fix …?
    Glad to provide as much additional info as required.
    Thank you in advance.

    • Mik


    Private Sub MetroID_NotInList(NewData As String, Response As Integer)
    ' Get confirmation of whether new Markets to be added to list

    Dim strMessage As String, strDocName As String, strLinkCriteria As String
    Dim dbsSmr As Database
    Dim rstMarkets As Recordset

    strMessage = "Do you wish to add " & NewData & _
    " to the list of Markets / Metro Areas?"

    If MsgBox(strMessage, vbOKCancel + vbQuestion) = vbOK Then
    ' Open recordset of the Markets table and add the NewData value
    Set dbsSmr = CurrentDb()
    > Set rstMarkets = dbsSmr.OpenRecordset("Markets")
    rstMarkets.AddNew


    rstMarkets!Metro = NewData
    rstMarkets.Update
    Response = acDataErrAdded ' Requery the list

    ' Open form to add data etc. for new Metros.
    ' Store form name in variable
    strDocName = "Markets"
    ' Set link criterion to Metros field = new Metros name
    strLinkCriteria = "Metro = '" & NewData & "'"
    ' Open the form at newly added record
    DoCmd.OpenForm strDocName, , , strLinkCriteria

    Else
    ' Return to the form and undo edit
    Response = acDataErrContinue
    DoCmd.DoMenuItem acFormBar, acEditMenu, acUndo, , acMenuVer70
    End If

    End Sub

  2. #2
    Minty is offline VIP
    Windows 10 Office 365
    Join Date
    Sep 2017
    Location
    UK - Wiltshire
    Posts
    3,003
    If you don't have (or ever had) a table or a query called Markets, then that code cannot have worked.

    In something of a rarity for Access, that error message is extremely accurate .
    It can't find the table or query called Markets.

    So either its been deleted, renamed or the code could not have worked.
    DLookup Syntax and others http://access.mvps.org/access/general/gen0018.htm
    Please use the star below the post to say thanks if we have helped !
    ↓↓ It's down here ↓↓

  3. #3
    MikF is offline Novice
    Windows 11 Access 2010 64bit
    Join Date
    Dec 2023
    Posts
    8
    That's what I thought, and indeed looked to see if for whatever reason I had renamed something to "Markets".
    Cannot find a table or query - or anything for that matter - named as such.
    Any ideas as to where it could be hiding ..??
    Thank you,
    - Mik

  4. #4
    Gicu's Avatar
    Gicu is offline VIP
    Windows 10 Access 2013 32bit
    Join Date
    Jul 2015
    Location
    Kelowna, BC, Canada
    Posts
    4,115
    Replace it with tblMetro and see what happens:
    Code:
    Set dbsSmr = CurrentDb()
    '> Set rstMarkets = dbsSmr.OpenRecordset("Markets")
    Set rstMarkets = dbsSmr.OpenRecordset("tblMetro")
    rstMarkets.AddNew
    Cheers,
    Vlad Cucinschi
    MS Access Developer
    http://forestbyte.com/

  5. #5
    MikF is offline Novice
    Windows 11 Access 2010 64bit
    Join Date
    Dec 2023
    Posts
    8
    Now it comes up
    'Error 13' Type Mismatch



    Private Sub MetroID_NotInList(NewData As String, Response As Integer)
    ' Get confirmation of whether new Markets to be added to list

    Dim strMessage As String, strDocName As String, strLinkCriteria As String
    Dim dbsSmr As Database
    Dim rstMarkets As Recordset

    strMessage = "Do you wish to add " & NewData & _
    " to the list of Markets / Metro Areas?"

    If MsgBox(strMessage, vbOKCancel + vbQuestion) = vbOK Then
    ' Open recordset of the Markets table and add the NewData value
    Set dbsSmr = CurrentDb()
    Set rstMarkets = dbsSmr.OpenRecordset("tblMetro")
    rstMarkets.AddNew
    rstMarkets!Metro = NewData
    rstMarkets.Update
    Response = acDataErrAdded ' Requery the list

    ' Open form to add data etc. for new Metros.
    ' Store form name in variable
    strDocName = "Markets"
    ' Set link criterion to Metros field = new Metros name
    strLinkCriteria = "Metro = '" & NewData & "'"
    ' Open the form at newly added record
    DoCmd.OpenForm strDocName, , , strLinkCriteria

    Else
    ' Return to the form and undo edit
    Response = acDataErrContinue
    DoCmd.DoMenuItem acFormBar, acEditMenu, acUndo, , acMenuVer70
    End If


    End Sub

  6. #6
    MikF is offline Novice
    Windows 11 Access 2010 64bit
    Join Date
    Dec 2023
    Posts
    8
    Same problem is also occurring with the States field, and that has never been changed.

    Thanks again to anyone who may know how to remedy this.

  7. #7
    Gicu's Avatar
    Gicu is offline VIP
    Windows 10 Access 2013 32bit
    Join Date
    Jul 2015
    Location
    Kelowna, BC, Canada
    Posts
    4,115
    Your variables are not fully qualified, please try this:
    Code:
    Private Sub MetroID_NotInList(NewData As String, Response As Integer)
    ' Get confirmation of whether new Markets to be added to list
    
    
    Dim strMessage As String, strDocName As String, strLinkCriteria As String
    Dim dbsSmr As DAO.Database
    Dim rstMarkets As DAO.Recordset
    
    
    strMessage = "Do you wish to add " & NewData & _
    " to the list of Markets / Metro Areas?"
    
    
    If MsgBox(strMessage, vbOKCancel + vbQuestion) = vbOK Then
    ' Open recordset of the Markets table and add the NewData value
    Set dbsSmr = CurrentDb()
    Set rstMarkets = dbsSmr.OpenRecordset("tblMetro") 'Vlad: was Markets
    rstMarkets.AddNew
    rstMarkets!Metro = NewData
    rstMarkets.Update
    Response = acDataErrAdded ' Requery the list
    
    
    ' Open form to add data etc. for new Metros.
    ' Store form name in variable
    strDocName = "Markets"
    ' Set link criterion to Metros field = new Metros name
    strLinkCriteria = "Metro = '" & NewData & "'"
    ' Open the form at newly added record
    DoCmd.OpenForm strDocName, , , strLinkCriteria
    
    
    Else
    ' Return to the form and undo edit
    Response = acDataErrContinue
    DoCmd.DoMenuItem acFormBar, acEditMenu, acUndo, , acMenuVer70
    End If
    End Sub
    Cheers,
    Vlad Cucinschi
    MS Access Developer
    http://forestbyte.com/

  8. #8
    Join Date
    Jan 2017
    Location
    Swansea,South Wales,UK
    Posts
    4,940
    As you have Markets all over the place, if it has been working before, then I would have to say there was a table called Markets?
    Please use # icon on toolbar when posting code snippets.
    Cross Posting: https://www.excelguru.ca/content.php?184
    Debugging Access: https://www.youtube.com/results?sear...bug+access+vba

  9. #9
    Gicu's Avatar
    Gicu is offline VIP
    Windows 10 Access 2013 32bit
    Join Date
    Jul 2015
    Location
    Kelowna, BC, Canada
    Posts
    4,115
    I agree, looking at the code again towards the end is attempting to open a form called "Markets" (strDocName = "Markets") which from post #1 should be "frmMetro"....

    Cheers,
    Vlad Cucinschi
    MS Access Developer
    http://forestbyte.com/

  10. #10
    MikF is offline Novice
    Windows 11 Access 2010 64bit
    Join Date
    Dec 2023
    Posts
    8
    Seems to have gotten farther along, but now stalls at ..
    DoCmd.OpenForm strDocName, , , strLinkCriteria


    Private Sub MetroID_NotInList(NewData As String, Response As Integer)
    ' Get confirmation of whether new Markets to be added to list




    Dim strMessage As String, strDocName As String, strLinkCriteria As String
    Dim dbsSmr As DAO.Database
    Dim rstMarkets As DAO.Recordset




    strMessage = "Do you wish to add " & NewData & _
    " to the list of Markets / Metro Areas?"




    If MsgBox(strMessage, vbOKCancel + vbQuestion) = vbOK Then
    ' Open recordset of the Markets table and add the NewData value
    Set dbsSmr = CurrentDb()
    Set rstMarkets = dbsSmr.OpenRecordset("tblMetro") 'Vlad: was Markets
    rstMarkets.AddNew
    rstMarkets!Metro = NewData
    rstMarkets.Update
    Response = acDataErrAdded ' Requery the list




    ' Open form to add data etc. for new Metros.
    ' Store form name in variable
    strDocName = "Markets"
    ' Set link criterion to Metros field = new Metros name
    strLinkCriteria = "Metro = '" & NewData & "'"
    ' Open the form at newly added record
    > DoCmd.OpenForm strDocName, , , strLinkCriteria




    Else
    ' Return to the form and undo edit
    Response = acDataErrContinue
    DoCmd.DoMenuItem acFormBar, acEditMenu, acUndo, , acMenuVer70
    End If
    End Sub

  11. #11
    Gicu's Avatar
    Gicu is offline VIP
    Windows 10 Access 2013 32bit
    Join Date
    Jul 2015
    Location
    Kelowna, BC, Canada
    Posts
    4,115
    Look at my latest post, replace the Markets with frmMetro.
    Vlad Cucinschi
    MS Access Developer
    http://forestbyte.com/

  12. #12
    MikF is offline Novice
    Windows 11 Access 2010 64bit
    Join Date
    Dec 2023
    Posts
    8
    That worked.
    *Sincerely appreciate* the help and input ..!!
    A few more of these are off as well, in much the same way.



    As follows from another form - same idea - where need to add a new City to that table.

    Its stalling at ..
    Set rstCities = dbsSmr.OpenRecordset("tblCities")


    Private Sub CityID_NotInList(NewData As String, Response As Integer)
    ' Get confirmation of whether new Cities to be added to list.
    'This is all the code needed to open frmCities and add a new city. No updates/etc required.

    Dim strMessage As String, strDocName As String, strLinkCriteria As String
    Dim dbsSmr As Database
    Dim rstCities As Recordset

    strMessage = "Do you wish to add " & NewData & _
    " to the list of Cities?"

    If MsgBox(strMessage, vbOKCancel + vbQuestion) = vbOK Then
    ' Open recordset of the Cities table and add the NewData value
    Set dbsSmr = CurrentDb()
    Set rstCities = dbsSmr.OpenRecordset("tblCities")
    rstCities.AddNew
    rstCities!City = NewData
    rstCities.Update
    Response = acDataErrAdded ' Requery the list

    ' Open form to add data etc. for new Cities.
    ' Store form name in variable
    strDocName = "frmCities"
    ' Set link criterion to Cities field = new Cities name
    strLinkCriteria = "City = '" & NewData & "'"


    ' Open the form at newly added record
    'You must open frmCities in dialog mode, so that the code in the NotInList
    'event doesn't continue until the form has been filled out and closed.
    'Change this line: DoCmd.OpenForm strDocName, , , strLinkCriteria to:


    DoCmd.OpenForm strDocName, _
    WhereCondition:=strLinkCriteria, _
    WindowMode:=acDialog
    Else
    ' Return to the form and undo edit
    Response = acDataErrContinue
    DoCmd.DoMenuItem acFormBar, acEditMenu, acUndo, , acMenuVer70
    End If


    End Sub

  13. #13
    moke123's Avatar
    moke123 is offline Me.Dirty=True
    Windows 11 Office 365
    Join Date
    Oct 2012
    Location
    Ma.
    Posts
    1,654
    A few more of these are off as well, in much the same way.
    If you are doing these repeatedly, you should use a generic sub

    Code:
    ' usage..... Response = AddNewToList(NewData, "tblCities", "txtCity", "Cities")
    '
    Public Function AddNewToList(NewData As String, stTable As String, _
        stFieldName As String, strPlural As String, _
        Optional strNewForm As String) As Integer
        On Error GoTo err_proc
        'Adds a new record to a drop down box list
        'If form name passed, then open this form to the newly created record
     
        'Declare variables
        Dim rst As DAO.Recordset
        Dim IntNewID As Long
        Dim strPKField As String
        Dim strMessage As String
     
        ' Display message box asking if user wants to add the new item
        strMessage = "'" & NewData & "' is not in the current list. " & Chr(13) & Chr(13) & _
            "Do you want to add it to the list of " & strPlural & "?" & Chr(13) & Chr(13) & _
            "(Please check the entry before proceeding)."
     
        If MsgBox(strMessage, vbYesNo + vbQuestion + vbDefaultButton2, "Add New Data") = vbYes Then
            Set rst = CurrentDb.OpenRecordset(stTable, , dbAppendOnly)
            rst.AddNew
            rst(stFieldName) = NewData                'Add new data from combo box
            strPKField = rst(0).Name                  'Find name of Primary Key (ID) Field
            IntNewID = rst.Fields(0)
            rst.Update
            rst.Move 0, rst.LastModified
            'IntNewID = rst(strPKField)
     
            'if a form specified, then open the form with the primary key equal to the new record ID as the criteria
            If strNewForm <> "" Then DoCmd.OpenForm strNewForm, , , strPKField & "=" & IntNewID, , acDialog
     
            AddNewToList = acDataErrAdded                'Set response 'Data added'
        Else
            AddNewToList = acDataErrContinue             'Set response 'Data NOT added'
        End If
     
    exit_proc:
        On Error Resume Next
        rst.Close
        Set rst = Nothing
        Exit Function
     
    err_proc:
        MsgBox "Error in Function: 'AddNewToList'" & Chr(13) & Err.Description, , "Function Error"
        Resume exit_proc
     
    End Function
    'Notes:
    '1. The Primary Key field must be numeric (long integer) and must always be the first field in the table.
    '2. The 'Limit to List' property of the combo box must be set to 'Yes'
    '3. strNewForm is opened in edit mode as the new record is added first and the form then opened to that record. A consequence of this is that other fields in the table must have their 'Required' property set to 'No' or a (valid) default property value set in the table design.
    '4. FieldNamePlural is there simply to make the message grammatically correct; in the AddNewToList code the message box string generated as: strMessage = "'" & NewData & "' is not in the current list. " & Chr(13) ..... would result in the warning message (e.g.):
    'London' is not in the current list. "
    'Do you want to add it to the list of Cities?
    '(Please check the entry before proceeding).
    '5. If an edit form is opened (strNewForm <> "") then the field that is displayed in the combo box should be in a locked control on the form, alternatively remove the acDialog argument and ensure the combo box is re-queried when the form is closed.
    '6. The form 'strNewForm' should have it's 'Allow Additions' and 'Data Entry' properties set to 'No' to prevent users from adding additional entries to the entry requested by the Not In List event.
    'Enjoy!
    'Edit1: 18/02/2013: Added Note 4
    'Edit2: 02/03/2014: Added Notes 5 & 6.
    If this helped, please click the star * at the bottom left and add to my reputation- Thanks

  14. #14
    Gicu's Avatar
    Gicu is offline VIP
    Windows 10 Access 2013 32bit
    Join Date
    Jul 2015
    Location
    Kelowna, BC, Canada
    Posts
    4,115
    moke123's code would make it easier for you to add this functionality for other combos; for the code in post #12 please try to add "DAO." to the declaration statements for the database and recordset variables (the default is a ADO recordset but you are working with a DAO one).

    Cheers,
    Vlad Cucinschi
    MS Access Developer
    http://forestbyte.com/

  15. #15
    moke123's Avatar
    moke123 is offline Me.Dirty=True
    Windows 11 Office 365
    Join Date
    Oct 2012
    Location
    Ma.
    Posts
    1,654
    Quote Originally Posted by Gicu View Post
    moke123's code would make it easier for you to add this functionality for other combos; for the code in post #12 please try to add "DAO." to the declaration statements for the database and recordset variables (the default is a ADO recordset but you are working with a DAO one).

    Cheers,
    Not really my code. Found it somewhere years and years ago.
    If this helped, please click the star * at the bottom left and add to my reputation- Thanks

Page 1 of 2 12 LastLast
Please reply to this thread with any new information or opinions.

Similar Threads

  1. Replies: 6
    Last Post: 10-29-2020, 12:08 PM
  2. CSV Export no longer working.
    By JRodko in forum Import/Export Data
    Replies: 4
    Last Post: 11-20-2019, 08:34 AM
  3. report no longer working
    By chriswrcg in forum Reports
    Replies: 8
    Last Post: 01-22-2019, 05:13 PM
  4. Form no longer working
    By ceatana in forum Forms
    Replies: 3
    Last Post: 05-22-2018, 12:55 PM
  5. NotInlist Event not working properly
    By thanosgr in forum Programming
    Replies: 2
    Last Post: 06-14-2012, 01:46 PM

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •  
Other Forums: Microsoft Office Forums