Learn Microsoft Access Advanced Programming Techniques, Tips and Tricks.

Shifting Focus from one sub-form to the other.

Introduction.

Sample Form with two Sub-Forms:

The Focus movement Requirement

Last week we saw how to set focus to a particular field in a sub-form from the main form field.  I have not mentioned anything about the relationships between these three forms in the earlier example.  But, here it is important to know before we attempt to leave Focus from a record in the first sub-form and set focus to its corresponding record in the second sub-form.

Two related Sub-Forms and two issues to solve.

  1. Two related sub-forms need to link together, on the common Main Form. The first sub-form is directly linked to the main form.
  2. Setting focus on the Amount text box on the second sub-form, when Tab-key press transfers focus from the last text box (the School-Year) on the first sub-form.

Assume that the current record on the first sub-form (frm_Session) is the Session ID (Primary Key) field value 1.  Since the first sub-form is directly linked to the second sub-form (we will explore this aspect, i.e., establishing direct links between two sub-forms, a little later on this page) frm_Payments, the payment record with the SessionId (Foreign Key) field value 1 is displayed on that form too.  We want to transfer focus from the first sub-form Session record to its corresponding Payment record Amount field in the second sub-form. 

Normally, when you press Tab-Key on the last field of the current record, the insertion point moves to the first field of the next record on the same form (with SessionID value 2). Automatically the Payment record, linked to the Session record, also changes to synchronize with the Session ID value 2, because it is directly linked with the frm_session.  So the control is lost from the first record with SessionID field value 1 and we could not enter the Payment Value in the Amount field of the frm_Payment, for the same SessionID. We don't want this to happen, instead, we want the focus to move on to the frm_Payment's Amount field, to enter the payment value of SessionID 1. If you could not make out the total picture of the problem, then check the second image diagram.

So, the question is how to keep the Focus on the first record itself, when the focus is lost from the last field, and transfer the Focus to its corresponding record's Amount field on the second subform?

Linking Both Sub-Forms Together.

Before going into that, let us learn how to link both sub-forms directly, to synchronize related records on both subforms.

The first sub-form (frm_Session) is directly linked with the Main Form (frm_Students) on the common field Student ID (Primary Key) field, on Students Table, and Student ID (Foreign Key) on Session Table.

The current student record on the main form can have several session records on the frm_Session Form.  Each Session record on the Session sub-form will have one or more Payment records on the frm_Payment sub-form and have SessionID as Foreign Key.

The frm_Payments sub-form is directly linked to the frm_Session sub-form of the common SessionID field value. 

Linking Both Sub-Forms Together.

Two sub-forms cannot be linked together directly because a sub-form cannot be considered a Master Form by another Sub-Form.  When this kind of link (relationships) becomes necessary, like the above sub-forms, we can do it by simply transferring the first sub-form Key-field value in an Unbound Textbox on the Main form, and this Unbound Textbox that holds the SessionID value becomes part of the Main Form.  The Name of this Textbox can be used in the Link Master Field property of the second sub-form to establish a relationship with the first sub-form.

Check the following Design View of the above Forms:

You can see an Unbound TextBox with the yellow background, created specifically for linking the second sub-form (frm_Payments) to the first sub-form (frm_Session) through the Unbound Textbox on the frm_Students main Form.  This Textbox Name Property value is set as Session_ID, somewhat different than the actual field names in the sub-forms: SessionID. The child Label Caption I have changed to Session_ID for information.

The Session_ID TextBox’s Control Source Property is set with the following expression, to copy the SessionID value automatically from the current record on the frm_Session sub-form:

=[frm_Session].Form!SessionID

Once this is done, you can link the frm_Payments sub-form with the frm_Session sub-form through the Session_ID Texbox by setting the Link Master Field and Link Child Field properties of the frm_Payments sub-form, as shown below.

Link Master Field = Session_ID (the unbound Textbox name)
Link Child Field = SessionID  (the Payments Form’s Foreign Key field name)

Tackling the Real Problem

If you understood the subform's relationships then we can proceed with the real issue I have pointed out at the beginning of this Article.  We must be able to transfer control from the last field of a record in the first sub-form to its corresponding record in the second sub-form, without changing the current record on the first sub-form.  We need a small VBA program to do that job successfully.

Tip: You can try this out with three simple tables (Students, Session & Payments) with sample fields as shown on the Forms.  You may download a sample database, with the sample tables and forms, from the download link given at the bottom of this Article.

If you have the sample Tables and Forms organized as per the design shown above, you may open the frm_Students in normal view to do a sample run of what we are trying to achieve, without the VBA Code.

Tip:  If you have downloaded the sample database from the link given at the bottom of this article, then open the frm_Session in the design view, press F4 to display the Property Sheet, and Click on the School Year Field.  You will find [Event Procedure] in the On Got Focus event property.  Click on this property and click on the Build (. . .) Button to open the VBA Module.  Highlight and delete the entire code, except the first two lines: Option Compare Database & Option Explicit.  Save and close the form. You can copy and paste the deleted code from this page.

  1. Open the frm_Students in Normal View.

  2. Click on the first record on the frm_Session form to select the record with SessionID value 1.

  3. Check the presence of the related record on the frm_Payments sub-form, with the Session ID value 1.

  4. Press Tab Key to move the control to the last field School Year. 

    Note:  What we want at this point is, when you press the Tab Key one more time the control should jump from the current record on the frm_Session sub-form and set focus on its corresponding record with SessionID value 1, on the frm_Payments sub-form. 

  5. Now, press Tab Key to move out of the last data Field - School Year from frm_Session to go to Amount Field of frm_Payments.

But, it didn’t happen as we have expected, instead, the cursor moved down to the next record on the frm_Session, with SessionID value 2.  The related records on the frm_Payments also changed to Foreign-Key SessionID value 2 to match with the record on frm_Session.

We can do this task only with the help of the VBA Code.  The steps of our program are given below:

  1. When the Focus arrives on the School Year field on frm_Session, save the SessionID value into a memory variable SID.

  2. When the Focus is Lost (i.e., when the user presses Tab Key again) from the School Year, the Focus moves to the next record and at this point, the VBA Code searches through the form’s RecordsetClone for the SessionID value in memory Variable SID.

  3. When the record is found then the RecordsetClone Bookmark is saved into the bkmk String Variable.

  4. Copy the record set Bookmark into the frm_Session’s Bookmark control. 

    These steps reset the focus back to the previous record, from the second record, on the frm_Session sub-form. The frm_Payment record earlier changed, and before executing the code,  returns to the one matching the SessionID on the frm_Session record.

  5. Set Focus on the frm_Payments.

    When this happens the frm_Payments field with Tab Index value 0 receives the Focus.  At this point, we can move the Focus to any other field, if needed.  We will try this by setting the focus on the Amount field.

  6. Set focus on the Amount field on frm_Payments.

If you have the above Form ready, then copy and paste the VBA Code given below into the frm_Session’s VBA Module.

  1. Open the frm_Session form in the design view.
  2. Click on the School Year field to select it.

  3. Press F4 to display the Property Sheet of the School Year field.

  4. Find the On Got Focus event property and click to select it.

  5. Select [Event Procedure] from the drop-down control.

  6. Click on the Build (. . .) Button to open the Form’s VBA Module (known as Class Module).  You may find the following lines of Code in the Class Module.

    The VBA Code.

    Option Compare Database
    Option Explicit
    
    Private Sub SchoolYear_GotFocus()
    
    End Sub
  7. Copy and paste the following lines of Code overwriting the existing above lines of code in the Module:
    Option Compare Database
    Option Explicit
    'SID is declared as a global variable
    Dim SID As Long
    
    Private Sub SchoolYear_GotFocus()
    'Save the SessionID value in a Global variable
    SID = Me!SessionID
    End Sub
    
    Private Sub SchoolYear_LostFocus()
    '----------------------------------------------
    'This subroutine runs when the Focus is shifted 
    'from the SchoolYear field.
    '----------------------------------------------
    'Author : a.p.r. pillai
    'Date   : Jan/2013
    'All Rights Reserved by www.msaccesstips.com
    '----------------------------------------------
    Dim ctrl As Control, ctrl2 As Control
    Dim bkmk As String, rst As Recordset, j As Long
    Dim rstSID As Long
    
    'The following lines of code prevents shifting the focus
    'to the next record on the frm_Session sub-form, when the focus
    'is lost from the last field of frm_Session, in preparation to set focus
    'on a particular field on the corresponding record on the
    'frm_Payments sub-form.
    Set rst = Me.RecordsetClone 'frm_session's recordset
    rst.MoveFirst
    For j = 1 To rst.RecordCount
    rstSID = rst![SessionID]
    If rstSID = SID Then 'find the record matching the current record on frm_session
       'when match found save the record's recordset bookmark
       bkmk = rst.Bookmark
       'copy the recordset bookmark to the form
       'this will set the focus back on the same record
       'this will also ensure that the SessionID related Payment record
       'will be current on the frm_Payment form
       Me.Bookmark = bkmk
       'set focus on the first field
       Me.SessionID.SetFocus
       'break the loop
       Exit For
    End If
    rst.MoveNext
    Next
    rst.Close
    'transfer control to the frm_Payments Sub-form
    'Now the field with Tabindex number 0 have the default focus
    Set ctrl = Forms![frm_Students].Controls("frm_Payments")
    ctrl.SetFocus
    'Once the focus is shifted on the field with tabindex 0 within frm_Payment sub-form
    'we can move the focus to any other field within that form, if required
    Set ctrl2 = Forms![frm_Students]![frm_Payments].Form.Controls("Amount")
    ctrl2.SetFocus
    
    End Sub
    
  8. Save and Close the Form.

    Try out your Forms.

  9. Open the frm_Students in the normal view.

  10. Click on the first record on the frm_Session Form.

  11. Press Tab Key to move the focus to the School Year field and check the corresponding record on the frm_Payments form.

  12. Press Tab Key one more time to jump the control onto the frm_Payments sub-form record, with the same Session ID value,  and to set the Focus directly on the Amount field.

Download Demo-Database.

Download Demo SubForm.zip
Share:

Setting Focus on a field inside a Sub-Form

Introduction.

The Main Form (frm_Students) has two Sub-Forms (frm_Sessions and frm_Payment).  A sample image of such a Form is given below:


Sub-Form Container and Sub-Form.

Each Sub-Form on the main form is placed within a Sub-Form Container on the main form.  The Sub-Form has other controls (like Textboxes) within it and we cannot set focus directly on any of these controls, from outside the sub-form container.  That doesn’t mean that we cannot address the controls directly to retrieve or set the value into that control through VBA.

The Difference Between Setting Focus and Retrieving Values

Setting focus in the Amount field of frm_Payments directly, when frm_Payments doesn't have the focus on, through VBA is not possible.

Example:

'this statement will not work when frm_Payments doesn't have focus
Forms![frm_Students]![frm_Payments].Form.Amount.SetFocus

The above statement may highlight the Amount field, but the focus will not change to that field.

But, we can retrieve the value directly from the Amount field of frm_Payments, even when the focus is not ON on that form, with the following statement.

Example-2:

'this statement retrieves the Amount field value directly.
m_Amt = Forms![frm_Students]![frm_Payments].Form!Amount

When the frm_Payments sub-form has the focus ON you can address a control (say the Amount field) within that form to set the real focus on it.

It simply means that it takes two-step action to address a control within a sub-form to set focus on:

  1. Set focus on the sub-form container first.  Setting the Tab Index Value of the frm_Payment to 0 also works.
  2. Set focus on any control within the frm_Payments sub-form.

So, it is a two-step process and the following two VBA statements do the job:

Me.Payments.form.SetFocus
Me.Payments.form.Amount.SetFocus

The following version of the above statements is also valid:

Forms![frm_Students]![frm_Payments].SetFocus
Forms![frm_Students]![frm_Payments].Form.Amount.SetFocus

What Next...

Next, we will see how to jump from the last field of one sub-form record to its corresponding record field on the second sub-form directly.  If you think it is so easy after learning the above two lines, then think twice.

Share:

PRESENTATION: ACCESS USER GROUPS (EUROPE)

Translate

PageRank

Post Feed


Search

Popular Posts

Blog Archive

Powered by Blogger.

Labels

Forms Functions How Tos MS-Access Security Reports msaccess forms Animations msaccess animation Utilities msaccess controls Access and Internet MS-Access Scurity MS-Access and Internet Class Module External Links Queries Array msaccess reports Accesstips WithEvents msaccess tips Downloads Objects Menus and Toolbars Collection Object MsaccessLinks Process Controls Art Work Property msaccess How Tos Combo Boxes Dictionary Object ListView Control Query VBA msaccessQuery Calculation Event Graph Charts ImageList Control List Boxes TreeView Control Command Buttons Controls Data Emails and Alerts Form Custom Functions Custom Wizards DOS Commands Data Type Key Object Reference ms-access functions msaccess functions msaccess graphs msaccess reporttricks Command Button Report msaccess menus msaccessprocess security advanced Access Security Add Auto-Number Field Type Form Instances ImageList Item Macros Menus Nodes RaiseEvent Recordset Top Values Variables Wrapper Classes msaccess email progressmeter Access2007 Copy Excel Export Expression Fields Join Methods Microsoft Numbering System Records Security Split SubForm Table Tables Time Difference Utility WScript Workgroup database function msaccess wizards tutorial Access Emails and Alerts Access Fields Access How Tos Access Mail Merge Access2003 Accounting Year Action Animation Attachment Binary Numbers Bookmarks Budgeting ChDir Color Palette Common Controls Conditional Formatting Data Filtering Database Records Defining Pages Desktop Shortcuts Diagram Disk Dynamic Lookup Error Handler External Filter Formatting Groups Hexadecimal Numbers Import Labels List Logo Macro Mail Merge Main Form Memo Message Box Monitoring Octal Numbers Operating System Paste Primary-Key Product Rank Reading Remove Rich Text Sequence SetFocus Summary Tab-Page Union Query User Users Water-Mark Word automatically commands hyperlinks iSeries Date iif ms-access msaccess msaccess alerts pdf files reference restore switch text toolbar updating upload vba code