Solved subforms not updating properly

A lot of your requeries serve no purpose, do not just shotgun these out. Especially not in the on current event.

In the lstSubSubAuthor there was a requery of the combobox, and a requery of the lstSubAuthors and the Child0 subform. This was being done in the on current of lstSubSubAuthor so every single time a record changes by code or by user input. Unless data changes and needs to be reflected than the requery is doing nothing.

Code:
Private Sub Form_Current()
    Me.cboAuthor.Requery
End Sub
This does nothing of value. The combo is based on non changing list of data

Requerying Child0 as you had it designed from the lstSubSubAuthor should only happen if the object in the ChildO is lstSubAuthors and only after an Author has been added to a book. Because if you add an author to a book and that author did not previously have a book assigned then that author did not appear in the list. But again only after adding or deleting an author. Not every time a record changes.

Code:
Private Sub Form_AfterUpdate()
'Only needed if an author was added to a book and only if the list is authors
Dim authorID As Long
Dim frm As Access.Form
Set frm = Me.Parent.Parent.Child0.Form
If frm.Name = "lstSubAuthors" Then
   authorID = frm.authorID
   frm.Requery
   frm.Recordset.FindFirst "authorID = " & authorID
End If
End Sub

In the lstSubDetail again you were requerying the subBooks on the On current event. Again this does nothing of value. In fact the only thing that can change in subBooks is if the copywright or page number changes and you want to reflect that.

Code:
Private Sub Copyright_AfterUpdate()
  RequeryBookDetails
End Sub

Private Sub Form_AfterUpdate()
  RequeryBookDetails
End Sub
Private Sub Number_of_Pages_AfterUpdate()
    RequeryBookDetails
End Sub
Public Sub RequeryBookDetails()
   Dim BookID As Long
  Dim frm As Access.Form
  Set frm = Me.Parent.subBooks.Form
  BookID = Nz(frm.BookID, 0)
  frm.Requery
  frm.Recordset.FindFirst "BookID = " & BookID

End Sub

You only need to be doing requeries when data changes and you need to reflect that change on the screen. This should be done judiciously or you will get the problems you had.

One final thing. You need to fix your queries.
Your query qryAuthors is not a query of authors but a query of Authors and their book id.
I would make 3 useful queries for all of these (author, publisher, illustrator...)
qryAuthors (all authors)
qryAuthorsWithBooks (authors assigned to one or more books)
qryAuthorsWithoutBooks (Un assigned authors.)

You are using your qryAuthors in other queries and it is causing this duplication.

Code:
SELECT tblauthors.authorid,
       Iif(Isnull([lastname]), [firstname], Iif(Isnull([firstname]), [lastname],
                                            [lastname] & "," & [firstname])) AS
       Author,
       tblauthors.lastname,
       tblauthors.firstname
FROM   tblauthors
ORDER  BY Iif(Isnull([lastname]), [firstname],
          Iif(Isnull([firstname]), [lastname],
                    [lastname] & "," &
                    [firstname]));

qryAuthorsWithBooks
Code:
SELECT tblauthors.authorid,
       Iif(Isnull([lastname]), [firstname], Iif(Isnull([firstname]), [lastname],
                                            [lastname] & "," & [firstname])) AS
       Author,
       tblauthors.lastname,
       tblauthors.firstname
FROM   tblauthors
WHERE  (( ( EXISTS (SELECT authoridfk
                    FROM   tblbookauthors AS B
                    WHERE  tblauthors.[authorid] = b.authoridfk) ) <> false ))
ORDER  BY Iif(Isnull([lastname]), [firstname],
          Iif(Isnull([firstname]), [lastname],
                    [lastname] & "," &
                    [firstname])),
          tblauthors.authorid;

Unassigned or qryAuthorsWithoutBooks
Code:
SELECT tblauthors.authorid,
       tblauthors.lastname,
       tblauthors.firstname,
       tblbookauthors.bookidfk
FROM   tblauthors
       LEFT JOIN tblbookauthors
              ON tblauthors.authorid = tblbookauthors.authoridfk
WHERE  (( ( tblbookauthors.bookidfk ) IS NULL ));
 
I see now, why you made this form this way but you did yourself NO favor with this reuse. A simpler solution than all the code might have been to populate the other subforms with a different query depending on which of the types was selected from the unbound combo. And in that code, populate the master/child links appropriately so that Access can take care of linking the subforms.
6 of one, half-dozen of another. The amount of work is going to be the same either way. If the OP choose to link the two subforms using a master child link then they would have to write that code (less familar) to change the Master/Child links after each selection. Or each subform applies a filter. Or each selection could choose a different query. Pretty similar code.
 
I knew you were good, MajP, because I already use a lot of your stuff but you have truly pointed me in the right direction. I also knew about subqueries but did not know this was a place I needed them. Thank you so much.
 
I'm not ignoring you. I actually scrapped my subforms for one subform but quit to go to bed. TMI? This morning I went back to what was working .My problem is I'm short on time. This is a card catalog I built for our parochial school some years ago. I've learned a lot since but I don't want to throw out the baby with the water. Small bites. I'll get there. Thank you for your time.
 
Not sure if you did it but this would limit some code. Since all your subforms basically show two fields an ID field and a Display field, the trick is to alias the fields in your query to ID, and Display. Then have a textbox bound to ID and a textbox bound to Display in your new generic subform.

Then make queries all with an alias for these fields.
something like
qrylstAuthor
Select AuthorID as ID, [LastName] & ", " & [FirstName] as Display form tblAuthors Order By....

qrylstPublisher
Select PublisherID as ID, PublisherName as Display from tblPublishers

In cboList your Select Case then simply has to set the recordsource for Child0.Form

Now you can go back to the trick of having a hidden textbox, txtLink on the main form.
in you new GenericlstSubForm in the on current event add
me.parent.txtLink = nz(me.ID) 'No matter what query is loaded they all have an alias ID

In sub books the masterlink field will always be [TxtLink]

in the cboList code you would change the childlinkField

Code:
  dim frm as access.form
  dim subFrm as access.subform
  set frm = Me!Child0.form
  set subFrm = me!subBooks
  Select Case Me.cboLists.Value
        Case "Authors"
            frm.recordsource = "qryLstAuthors"
            subFrm.linkChildFields = "AuthorIDFK"
        Case "Illustrators"
            frm.recordsource = "qryIllustrators"
            subFrm.linkChildFields = "IllustratorIDFK"
        Case "Publishers"
            frm.recordsource = "qrylstPublishers"
            subFrm.linkChildFields = "PublisherIDFK"
        Case "Series"
            frm.recordsource = "qryLstSeries"
            ...
        Case "Status"
            frm.recordsource = "qryLstStatus"
            ...
        Case "Subjects"
            frm.recordsource = "qryLstSubjects"
 
    End Select
 
Yes! Got it! Instead of filtering on current?
 
Last edited:
Instead of filtering on current?
It is just one technique. Or you can still filter on the current record, but then in the generic subform you would need a select case to determie what to filter.

Select case me.recordsource
case qrylstAuthor
me.subBooks.form.filter = "AuthorIDFK = " & me.ID
case qryLstPublisher
me.subbooks.form.filter = "PublisherIDFK = " & me.id
.....
 
Pat Hartman, this is really something !!!

yet, some error are trigered during use...
I wil try to understand your way of thinking and doing the job and if is not too much, I will come back to you for guidance or help in fixing the bugs.

Thank you and I apreciate a lor your effort and patience with me
R
 
Pat Hartman, this is really something !!!

yet, some error are trigered during use...
I wil try to understand your way of thinking and doing the job and if is not too much, I will come back to you for guidance or help in fixing the bugs.

Thank you and I apreciate a lor your effort and patience with me
R
@Romio_1968
To be clear @Pat Hartman only fixed issues in the subform. @ClaraBarton developed the database. You may want to look at the overall design and pose questions to @ClaraBarton
Also use the search feature. I thought bookstores were going the way of video stores, but I am amazed there are lots of bookstores and library questions and examples on this forum.

 
Last edited:
A little help, again, pls

I am trying to replicate some of ClaraBarton's database
By now, I have a main AddTitle form an a subform that should add author (not finished yet)
Without the subform, the main form works as it should (at this time, again).
Yet, after the sub is embeded, the main does not work anymore.

Problems so far:
On opening the main Add_Title_Frm form, the Title_ID control labeled Cod Tiltu is filled with the new Title_ID record from Titles table (Autonumber), as it sould
It allows me to fill all the data in the main form
When I am moving (getting focus) to the sub form, the data from the mai suddenly get messed:
All fields except Call_No (label Cota) and DomainCombo_1 (label Domeniu principal) are wiped out and the Title_ID control indicates (New)

Annother thing, wile working with the forms in design view, sometimes a new empty record is added to Title table

Please help me debugging this.
Thank You


(Please nte that I posted the same issue here> Form-Subform Conflict )
 

Attachments

Last edited:
Ok, Mr. Hartman, I tried... see attached.
I didn't do it before, because frankly, yours didn't work and I didn't have time to figure out why.
Now I've spent the time and need a little more help. I think my problem is with the linkchildfield.
Thank you for your patience!
I know I'll need to add edit lists to the detail but I haven't gotten that far yet.
No rush. I have to go buy groceries.
 

Attachments

I did see what @Pat Hartman describes and fixed in mine. I was lost with all the closely named queries. I think now a lot of those are not used.
As Pat describes in the 1st subfomr you are linked to two many to many (authors and subjects). So I made 3 new queries. On for just authors (include author table no subject table), one for just subjects (vice versa), and one for the others (no subject or author tables)

I fixed the relink so you are prompted at startup if the tables are not linked and give a file browser to relink. I demoed an option group which I though was more intuitive. I added some color in the subform so the selected book is gold

Here was the issue
dupes.jpg
 

Attachments

Oh yes. I figured out by following your sample and it works very well. I have yet to add the actual edit/delete lists for each item. I didn't copy your forms in because I wanted to see exactly what was happening. I changed the update a little because it seemed a waste not to use that table. Deleted unused queries... Loaded your sample. Loaded your sample. Loaded your sample!
Code:
Public Sub UpdateList()
    Dim lst As Access.ListBox
    Dim subFrm As Access.SubForm
    Dim txtRowSource As String
    Dim txtChildLink As String
  
    txtRowSource = DLookup("[BookListQuery]", "[tblLists]", "[List] = '" & Me!cboLists.Value & "'")
    txtChildLink = DLookup("ChildLink", "tblLists", "List = '" & Me.cboLists.Value & "'")
    Set lst = Me.lstTypeDesc
    Set subFrm = Me!Books

    lst.RowSource = txtRowSource
    subFrm.LinkChildFields = txtChildLink

Small thing but it works. I thank you very, very much.
I appreciate what Mr. Hartman did too. :)
 
Couple of minor things. I would make that list box very tall because your list of authors, subjects is very large. Short lists with lots of record are painful to scroll. Then when user selects Status you can set it to a short height and tall for everything else. I saw you had the FAYT combo. I would consider doing an FAYT Listbox for these long lists. That way if you remember a first name, part of a name you can likely find it.
There is a class and examples to do this.
You will simply have to reinitialize for each list change.
There is a lot going on in this form, and I would maximize it and take up more realestate. It is really compact makeing it seemed cluttered. I am assuming you may not have gotten to it, since the other forms are all maximized.
 
As far as I can tell everything I posted synchs correctly, and no duplicates. Just did not notice what the OP did the first time. Not sure of what problem you have to fix? You seem kind of spun up about saving a handful of lines of code. Who cares? I went a different approach to demo an option group. More than one way to skin a cat.
More importantly I did not look at what you did because it does not work. The version you posted the form does not even open, just hangs.
 
Last edited:
Oh wait wait! I am using your form! I've learned so much from you... How can I Highlight the matching row in the Edit-Delete form to the listbox? If I use master and child it filters the whole thing down to one record.
1674961789173.png
 
Last edited:
Since the list sets txtLink (or whatever it is called) to authorID then the edit delete form should link
Master Link Fields: [txtLink]
Child Link Fields: [auhorID]

But why do you need another form to edit/delete? The edit form is not editable since one is a PK the other is calculated. If you want to delete just delete from the listbox.
If it was an edit form then it should be a single form view with author details (or whatever is in the list at that time). And as stated no need for a delete subform.
 
Oh you're right. That list is redundant and takes up too much real estate. Why oh why can't I wait to post until I've slept on it?
 

Users who are viewing this thread

Back
Top Bottom