Learn Microsoft Access Advanced Programming Techniques, Tips and Tricks.

Showing posts with label VBA. Show all posts
Showing posts with label VBA. Show all posts

Diminishing Balance Calc in Query

Introduction.

This is an offshoot of the earlier Function Running-Sum, in Query Column.  With few changes in the earlier Function RunningSum() we can easily calculate and find the loan balance-to-pay amount, after deducting the monthly paid amount, at each record level.

The loan amount is payable in monthly installments.   Our simple task is to show the diminishing balance of the loan amount against each record-level installment amount in a separate Column of the Query.  The last record will have the remaining balance payment amount.

Let us pretend that the Loan Repayable Total Amount is 1000.

Sample Query Recordset.

The sample installment payment detail records are taken from the earlier Post: Running-Sum in Query Column as given below.

The Query SQL that calls the DiminishingBal() Function.

The SELECT Query SQL that calls the DiminishingBal() Function, in a separate Column of the Query.

SELECT Table_Units.ID, Table_Units.Units, DiminishingBal([ID],"ID","Units","DiminishingQ1") AS DiminishingBalance
FROM Table_Units;

The Query Recordset Image, with the result in the last column,  is given below:

We are using the same Query record set used as a source for the earlier RunningSum() Function and used here also for demonstration purposes.  The Recordset should have a Unique value (Numeric or String) field and be used as the first parameter to the Function.

The Total Repayable Loan Amount is kept in a separate Table.

The Total Amount to be repaid to the Bank (1000) is kept in a separate Table with the following structure:

The DiminishingBal() Function VBA Code.

The VBA Code of DiminishingBal() Function is given below:

Option Compare Database
Option Explicit

'Declare a Generic Object
Dim D As Object

Public Function DiminishingBal(ByVal IKey As Variant, ByVal KeyFldName As String, ByVal SumFldName As String, ByVal QryName As String) As Double
'-----------------------------------------------------------
'Function: DiminishingBal()
'Purpose : Calculate Diminishing Balance in a separate Column
'The Query can be used as source for other Processing needs,
'for Form View or Report
'-----------------------------------------------------------
'Author  : a.p.r. pillai
'Date    : December 2019
'Rights  : All Rights Reserved by www.msaccesstips.com
'-----------------------------------------------------------
'Parameter List, in the Order of it's placement
'1. Key Value Data Field
'2. Key-Field Name in String Format
'3. Field-Name for Calcuating Running Sum in String Format
'4  Query-Name in String Format
'-----------------------------------------------------------
'Remarks: The Key-Value Field should have Unique Numeric or
'String Values.
'-----------------------------------------------------------
Static K As Long, X As Double, fld As String, y As Long
Dim p As Variant

On Error GoTo DiminishingBal_Err

y = DCount("*", QryName)
'If the Function is not called by the same Query
'then initialize Dictionary Object and Variables
If SumFldName <> fld Or K > y Then
   fld = SumFldName
   Set D = Nothing
   K = 0
   X = 0
End If


K = K + 1
If K = 1 Then 'The major process of the function starts here
    Dim DB As Database, rst As Recordset
    
    'Create and instantiate the Dictionary Object
    Set D = CreateObject("Scripting.Dictionary")
    
    'Get Loan Repayable Amount
    X = DLookup("[LoanAmt]", "tblRepay", "[id] = 1")
    
    'Open the EMI Recordset
    Set DB = CurrentDb
    Set rst = DB.OpenRecordset(QryName, dbOpenDynaset)
    'Calculate cumulative record-level summary and
    'add the value into Dictionary Object as it's Item
    While Not rst.EOF And Not rst.BOF
    'read the record summary field value and add it to total
         X = X - rst.Fields(SumFldName).Value
    'read current record key field value
         p = rst.Fields(KeyFldName).Value
    'add the total value to dictionay object
    'as Key, Item pair
         D.Add p, X
    ' repeat this process for all records
         rst.MoveNext
    Wend
    
    'close recordset and remove the database objects
    rst.Close
    Set rst = Nothing
    Set DB = Nothing
    
    'Retrieve the first item from Dictionary,
    'using the first Key passed as parameter,
    'and return to the function calling record in the Query
    
   DiminishingBal = D(IKey)
Else
   'Subsequent calls with the record Key passed as parameter
   'will retrieve other record values from Dictionary and
   'returns to their corresponding records in the Query.
   
   DiminishingBal = D(IKey)
End If

'A control forcing to initialize the static variables
'when the program is rerun for the same query.
   If K = y Then
      K = K + 1
   End If

DiminishingBal_Exit:
Exit Function

DiminishingBal_Err:
MsgBox Err & ":" & Err.Description, vbOKOnly, "DiminishingBal()"
Resume DiminishingBal_Exit
End Function

How the Function Works.

In the Global declaration area of the VBA Module, Variable D is declared as an Object.

The DiminishingBal() Function needs four parameters:

  1. A Unique Value Field (Numeric or String Values) is the first parameter.  The parameter is declared as a Variant data Type.
  2. The Unique Value’s Field Name is the second parameter in String format.
  3. The Loan Installment Value Field Name.
  4. The Query Name is the fourth Parameter.
  5. Four Static Variables K, X, fld, and y are declared.  They must be Static Variables to retain their values between repeated calls of the Function, from each record of the Query.  The Variable p is declared as a Variant Type normal variable, to hold the Key-Value (either Numeric or String) of each record.

    The DCount() Function takes the record count of the Query in Variable y. The Value in this Variable is used as a control to check when to Reset the Static Variable Values to their initial Values and to remove the Dictionary Object from memory.  This control is necessary if the same Query is run more than once, consecutively.

    1. If the value in the control-variable K is more than the Query record count in variable y then resets the Static variables to their initial values and the Dictionary Object is deleted from memory.
    2. Or, If the installment value Field Name is different, from the field name saved in Variable fld during the last call of the function,  then it assumes that the Function is called from a different Query Column and resets the Static Variable Values. The Dictionary object is deleted from memory.

    Next, Variable K is incremented by 1.  When K=1 the main action of the Function starts.  The Database and Recordset Objects are declared in the DB and the rst Variables respectively.

    In the next executable statement Set D = CreateObject("Scripting.Dictionary") creates the Dictionary Object with the CreateObject() method and assigns it to the Object variable D, which was declared in the Global Area of the Module.

    There are other ways to declare and use this Object by adding the Microsoft Scripting Runtime File to the Microsoft Access Reference Library List.  After that you can create an instance of the Dictionary Object in the following way:

    Dim D As Dictionary
    Set D = New Dictionary
    

    If you are new to the Dictionary Object and its usage visit the Post: Dictionary Object Basics.  There are five Posts on this Topic, and you can find the links at the end of this Page.

    Next we need the value of repayable total Loan Amount and retrieves it from it’s Table tblRepay with the Dlookup() Function in the statement: X = DLookup("[LoanAmt]", "tblRepay", "[id] = 1").  There is only one record in the Table with ID number 1 and you may omit the criteria part.

    The Query Recordset is open to read records one by one. The first record’s amount, paid to the bank, is deducted from the Loan Amount (1000) in Variable X.  The Unique Key value of the record is retrieved from the record and saved in variable p, in the next statement.

    The balance loan amount, calculated after deducting the repaid Amount, is added to the Dictionary Object, with Dictionary Object’s  Add Method, as its Item Value, with the Unique Key field value in the variable p as Dictionary-Key in the statement: D.Add p, X. The Dictionary’s Add method always adds its Item value in Key, Item pairs.

    Note: If the Key-Value is not Unique then the Add method fails and will end up with Errors.

    With the rst.MoveNext statement takes the next record for the same sequence of processing and adds the result value to the Dictionary Object.

    This way individual record value is deducted from the remaining balance loan amount at that level and added to the Dictionary Object as its Item.

    Note: Here, you may ask why the Dictionary Object is chosen to hold all the calculated values rather than in an Array.  Yes, It can be done, but that method needs more statements to store and retrieve the values in a Two Dimensional Array. It will become more complicated when the Query Record’s Unique Key Value is in String form.  The Dictionary Object allows the value retrieved in either sequential or random order based on its Key.  Here, the Random method works fine with the Key-Value Type in the Numeric or String form.

    When all the record processing is complete the record set and Database Objects are closed.

    What you have to keep in mind at this point is that still the value in variable K=1 and the first Parameter IKey retains the first records Unique Id Value.  At the first record level call of the function DiminishingBal() itself, we have calculated all the record level balance loan amount values, one by one, and added the result to the Dictionary Object as its Items. The function parameter IKey still holds the first record’s Unique ID value. That is the reason why we have used a separate variable p for individual record key values while processing all the records.

    So, the entire record level processing is done during the first call of the function, initiated from the first record of the Query, and all the record level result values are held in temporary storage in the Dictionary Object.

    The next statement DiminishingBal = D(IKey) retrieves the first value and added to the Dictionary using the unique parameter value IKey  and returns the value to the calling first record of the Query.

    The next call from the second record of the Query increments the variable K, by 1 (now K=2), and the program takes to the ELSE path of the IF. . .Then statement, retrieves the second Item value from the Dictionary Object, using the IKey parameter, and returns it to the respective record of the Query.

    The rest of the DiminishingBal() function call, from the remaining records, will route the program control only through the ELSE  path, because the value in Variable K is greater than one, retrieves the values from Dictionary Item, and returns it to the function calling record.

    The Next If . . . Then statement checks whether the value in variable K = y or notVariable y holds the total record count of the Query.  If it is found True then it assumes that the last call of the DiminishingBal() function has arrived.  At this point, the K Variable is made greater than the value in variable y.

    This is necessary to initialize the Static Variables during the rerun of the same Query. In case of any change made on the Source Data before rerun, it will not reflect on the balance amount calculated earlier, because it will keep taking the ELSE route of the If . . . Then statement and retrieves the old value from Dictionary Object.

    The Demo Database, with all the necessary Objects and the Code Module, is attached for your convenience to download and try it out straight away.


    Dictionary Object Links.

    1. Dictionary Objects Basics
    2. Dictionary Object Basics- 2
    3. Sorting Dictionary Object Keys and Items
    4. Display Records from Dictionary
    5. Add Class Objects as Dictionary Items
    6. Update Class Object Dictionary Item
Share:

Sorting Dictionary Object Keys and Items

Introduction.

Sorting or indexing table records is a commonly used and important task of organizing data in the correct order, enabling faster retrieval of information through index keys.

In the case of the Dictionary Object, however, there is already a built-in mechanism to directly retrieve information using its unique keys.

Still, if you would like to learn how to sort the values stored in a Dictionary Object, let’s try a simple demonstration. We will reuse the sample data created in earlier example programs as input for our sorting routine. The sample VBA code with the test data is shown below.

The DSort_Test() Main Procedure.

Public Sub DSort_Test()
Dim d As Dictionary
Dim mkey
Dim Title As String
Dim i As Long
Dim vKey() As Variant, vItem() As Variant

Set d = New Dictionary

'Set Key-Text Compare Mode
d.CompareMode = 1 'Text Compare(nancy = NANCY = Nancy = NaNCy)
 
'Syntax: obj.Add "Key", "Content"

'Countries and Capitals
d.Add "Belgium", "Brussels"
d.Add "Italy", "Rome"
d.Add "Canada", "Ottawa"
d.Add "USA", "Washington D.C."
d.Add "Denmark", "Copenhagen"
d.Add "Australia", "Canberra"
d.Add "France", "Paris"
d.Add "Saudi Arabia", "Riyadh"

Title = "UNSORTED LISTING"
GoSub Output_Section

ReDim vKey(1 To d.Count) As Variant
ReDim vItem(1 To d.Count) As Variant

'Load Key,Item pairs into two Variant Arrays
i = 1
For Each mkey In d.Keys
  vKey(i) = mkey
  vItem(i) = d(mkey)
  i = i + 1
Next

'Pass the Array to Bubble Sort Program
Call DBubbleSort(vKey, vItem)

d.RemoveAll 'Remove existing Dictionary Object
Set d = New Dictionary 'instantiate new Dictionary Object

'Re-create Dictionary Object with Sorted Array contents
For i = 1 To UBound(vKey)
   d.Add vKey(i), vItem(i)
Next

Title = "LISTING AFTER SORT"
GoSub Output_Section

Exit Sub

Output_Section:
'Print Sorted Dictionary Object contents
Debug.Print
Debug.Print Title
Debug.Print "---------------------"

For Each mkey In d.Keys
   Debug.Print mkey, d(mkey)
Next
Return

End Sub

In our earlier programs, the Dictionary keys (country names) were manually entered in alphabetical order. However, in this example, we have intentionally mixed up their order. We will pass this unsorted data to a sorting routine and retrieve it back in alphabetical order.

Unfortunately, the Dictionary Object does not provide a built-in way to rearrange its data directly. To achieve sorting, we must first copy the keys and their corresponding item values from the Dictionary into two separate arrays. These arrays can then be passed to a sorting routine to return the data in the desired order.

The Coding Steps.

The Algorithm of the Code segment, after creating the Dictionary Data items in the above program, is given below.

  1. Take a Listing of Unsorted Data from the Dictionary Object.

  2. Define two Array Variables: One for Keys and another for Item Values (if  Items are  Objects, then the second declaration must be for an Object of the Item’s Type).

  3. Read Dictionary Keys and Item Values and load them into separate Arrays.

  4. Pass the Arrays to the Sort Routines as ByRef Parameters.

  5. Remove the existing Dictionary Object and instantiate it as a new dictionary Object, with the same name.

  6. Read the Sorted Keys and Items from the Array and Add them to the new Dictionary Object.

  7. Take the listing of sorted data from the recreated Dictionary Object.

BubbleSort() Routine.

The Bubble-Sort VBA Code is given below:

Public Sub DBubbleSort(varKey() As Variant, varItem() As Variant)
Dim j As Long, k As Long
Dim tmp1 As Variant, tmp2 As Variant

For j = 1 To UBound(varKey) - 1
   For k = j + 1 To UBound(varKey)
      If varKey(k) < varKey(j) Then 'change < to > for Descending Order
      
'save first Key, Item value pairs in temporary variable
          tmp1 = varKey(j)
          tmp2 = varItem(j)

'replace first set of values with second value set
          varKey(j) = varKey(k)
          varItem(j) = varItem(k)
          
'replace second value set with saved values
          varKey(k) = tmp1
          varItem(k) = tmp2
      End If
   Next k
Next j

End Sub

The Unsorted and Sorted listing dumped on the Debug window image is given below:

UNSORTED LISTING
---------------------
Belgium       Brussels
Italy         Rome
Canada        Ottawa
USA           Washington D.C.
Denmark       Copenhagen
Australia     Canberra
France        Paris
Saudi Arabia  Riyadh

LISTING AFTER SORT
---------------------
Australia     Canberra
Belgium       Brussels
Canada        Ottawa
Denmark       Copenhagen
France        Paris
Italy         Rome
Saudi Arabia  Riyadh
USA           Washington D.C.

The Dictionary Keys, with Item Values, are sorted in Ascending Order

Sorting Reverse Order (Z-A).

With a slight change in the Key comparison statement, we can make the program sort the items in Descending Order.  Replace the Less Than Symbol (<) with the Greater Than Symbol (>) in the DBubbleSort program to sort the items in Descending Order, as shown below.

Existing comparison statement:

If varKey(k) < varKey(j) Then

change to

If varKey(k) > varKey(j) Then

The QuickSort() Sorts The Data Quickly.

If the Dictionary Object contains a large volume of data, then Bubble-Sort may not be as efficient as the QuickSort method.  We have the QuickSort program too for sorting Dictionary Data. 

Sample QuickSort VBA Code is given below:

Public Function DictQSort(DxKey As Variant, DxItem As Variant, lngLow As Long, lngHi As Long)
Dim tmpKey As Variant, tmpItem As Variant, midKey As Variant
Dim t_Low As Long, t_Hi As Long

midKey = DxKey((lngLow + lngHi) \ 2)
t_Low = lngLow
t_Hi = lngHi

While (t_Low <= t_Hi)
   While (DxKey(t_Low) < midKey And t_Low < lngHi)
      t_Low = t_Low + 1
   Wend
  
   While (midKey < DxKey(t_Hi) And t_Hi > lngLow)
      t_Hi = t_Hi - 1
   Wend

   If (t_Low <= t_Hi) Then
      tmpKey = DxKey(t_Low)
      tmpItem = DxItem(t_Low)
      
      DxKey(t_Low) = DxKey(t_Hi)
      DxItem(t_Low) = DxItem(t_Hi)
      
      DxKey(t_Hi) = tmpKey
      DxItem(t_Hi) = tmpItem
      
      t_Low = t_Low + 1
      t_Hi = t_Hi - 1
   End If
   
  If (lngLow < t_Hi) Then DictQSort DxKey, DxItem, lngLow, t_Hi 'recursive call
  If (t_Low < lngHi) Then DictQSort DxKey, DxItem, t_Low, lngHi 'recursive call
Wend
End Function

You may run the DictQSort() Program from the main Program DSort_Test(), by replacing the statement that calls the DBubbleSort() Sub-Routine, with a Call to the DictQSort() Function, as shown below:

Replace:

Call DBubbleSort(vKey, vItem)

with

Call DictQSort(vKey, vItem, LBound(vKey), UBound(vKey))

You may not notice any significant difference in execution time between the two programs with this small dataset. However, when working with a large volume of data, the QuickSort method completes the task in only a fraction of the time taken by the Bubble Sort program.

In these sorting procedures, the Keys and their corresponding Item values are first copied into two separate arrays before being passed to the sorting routine. Once the data is sorted, it is added back into a new Dictionary Object, and the old one is removed.

We can achieve the same result using a simpler approach. We only need to sort the Keys in the desired order—either ascending or descending. Using these sorted Keys, we can retrieve the corresponding Item values from the original Dictionary and add them to a new Dictionary Object in the sorted order. Finally, the old unsorted Dictionary Object can be discarded.

The modified version of the top program, with a built-in Bubble Sort Code, is given below.

Public Sub DSort_Test2()
Dim d As Dictionary
Dim y As Dictionary
Dim mkey, j As Long, k As Long
Dim Title As String
Dim i As Long
Dim vKey() As Variant

Set d = New Dictionary

'Set Key-Text Compare Mode
d.CompareMode = 1 'Text Compare(nancy = NANCY = Nancy = NaNCy)
 
'Syntax: obj.Add "Key", "Content"

'Countries and Capitals
d.Add "Belgium", "Brussels"
d.Add "Italy", "Rome"
d.Add "Canada", "Ottawa"
d.Add "USA", "Washington D.C."
d.Add "Denmark", "Copenhagen"
d.Add "Australia", "Canberra"
d.Add "France", "Paris"
d.Add "Saudi Arabia", "Riyadh"

Title = "UNSORTED LISTING"
'Print Unsorted Dictionary Object contents
Debug.Print
Debug.Print Title
Debug.Print "---------------------"

For Each mkey In d.Keys
   Debug.Print mkey, d(mkey)
Next

ReDim vKey(1 To d.Count) As Variant
'Load Keys into Variant Array
i = 1
For Each mkey In d.Keys
  vKey(i) = mkey
  i = i + 1
Next
'Bubble Sort the Keys in Ascending Order
For j = 1 To UBound(vKey) - 1
   For k = j + 1 To UBound(vKey)
       If vKey(k) < vKey(j) Then 'Ascending Order
          mkey = vKey(j)
            vKey(j) = vKey(k)
          vKey(k) = mkey
       End If
    Next k
Next j
'end of Sort

'create sorted Data in a new Dictionary Object
Set y = New Dictionary
For j = 1 To UBound(vKey)
  y.Add vKey(j), d(vKey(j))
Next

'Delete old unsorted Dictionary Object d
d.RemoveAll

Debug.Print
Title = "LISTING AFTER SORT"
Debug.Print Title
Debug.Print "---------------------"
For Each mkey In y.Keys
   Debug.Print mkey, y(mkey)
Next

End Sub

In this example, the Dictionary Keys are first loaded into the vKey() Variant Array. The Bubble Sort procedure then rearranges the Keys in the desired order.

Using these sorted Keys, the corresponding Item values are retrieved from the original Dictionary Object and written into a new Dictionary Object, maintaining the order of the sorted country names.

In the subsequent printing section, the sorted country names and their capitals are printed in the Debug Window from the new Dictionary Object.

However, do we really need to recreate a new Dictionary Object after sorting the Keys? Not necessarily. Since Dictionary Items can be accessed randomly using their Keys, it is sufficient to sort only the Keys and hold them in an Array. You can then use the sorted Keys to retrieve the Items from the existing Dictionary in the desired order (A–Z or Z–A). I’ll leave this approach as an exercise for you to try on your own.

MS-ACCESS CLASS MODULE

  1. MS-Access Class Module and VBA
  2. MS-Access VBA Class Object Arrays
  3. MS-Access Base Class and Derived Objects
  4. VBA Base Class and Derived Objects-2
  5. Base Class and Derived Object Variants
  6. Ms-Access Recordset and Class Module
  7. Access Class Module and Wrapper Classes

    COLLECTION OBJECT

  8. Ms-Access and Collection Object Basics
  9. Ms-Access Class Module and Collection Object
  10. Table Records in Collection Object and Form

    DICTIONARY OBJECT

  11. Dictionary Object Basics
  12. Dictionary Object Basics-2
  13. Sorting Dictionary Object Keys and Items
  14. Display Records from Dictionary to Form
  15. Add Class Objects as Dictionary Items
  16. Update Class Object Dictionary Item on Form
Share:

Wrapper Class Functionality Transformation

Introduction.

Last week, we created a new Wrapper Class named ClsTiles, which used the ClsArea Class twice within the same Class Module—one instance to store the room’s floor dimensions and another to store the tile dimensions—to calculate the number of tiles needed for the room.

In this new Wrapper Class Module, we will take the existing ClsVolume2 Class and transform it into a ClsSales Class. With a few cosmetic changes, we will give it a complete facelift inside the Wrapper Class, concealing its original purpose as a volume calculation class and repurposing it to calculate the selling price of products with a discount.

Interestingly, the ClsVolume2 Class already has all the necessary properties to store sales-related data: strDesc, dblLength, dblWidth, and dblHeight can be repurposed to represent Description, Quantity, Unit Price, and Discount Percentage, respectively.

Remember, the ClsVolume2 Class itself is a derived class, originally built using ClsArea as its base class.ClsVolume2 Class Re-Visited.

But, first, the VBA Code of ClsVolume2 Class Module  (the Base Class for our new ClsSales Class Module) is reproduced below for reference:

Option Compare Database
Option Explicit

Private p_Height As Double
Private p_Area As ClsArea

Public Property Get dblHeight() As Double
    dblHeight = p_Height
End Property

Public Property Let dblHeight(ByVal dblNewValue As Double)
    p_Height = dblNewValue
End Property

Public Function Volume() As Double
    Volume = CArea.dblLength * CArea.dblWidth * Me.dblHeight
End Function

Public Property Get CArea() As ClsArea
   Set CArea = p_Area
End Property

Public Property Set CArea(ByRef AreaValue As ClsArea)
  Set p_Area = AreaValue
End Property

Private Sub Class_Initialize()
Set p_Area = New ClsArea
End Sub

Private Sub Class_Terminate()
Set p_Area = Nothing
End Sub 

The only obstacle preventing us from using the ClsVolume2 Class directly for sales data entry is that its Property Procedure names—dblLength, dblWidth, and dblHeight—do not correspond to the required sales-related properties: Quantity, Unit Price, and Discount Percentage.

Fortunately, all these properties in the ClsVolume2 Class are of the Double data type, which is perfectly suitable for our sales calculations, so no data type changes are needed.

Similarly, the public function names Area() and Volume() are not meaningful in the context of sales, but their underlying calculation logic can be repurposed for sales-related computations without modification.

a) Area = dblLength * dblWidth is suitable for TotalPrice = Quantity * UnitPrice

b) Volume = Area * dblHeight is good for DiscountAmount = TotalPrice * DiscountPercentage

Here, we have two choices to use the ClsVolume2 as the ClsSales Class.

  1. The easiest approach is to create a copy of the ClsVolume2 Class and save it as a new Class Module named ClsSales. Then, update the Property Procedure names and public Function names to reflect sales-related values and calculations. You can also add any additional functions needed for handling sales operations directly within this new class module.

  2. Create a Wrapper Class based on the ClsVolume2 Base Class. In the Wrapper Class, implement corresponding property procedures and public functions that encapsulate and rename the Base Class’s property procedures and functions, effectively masking their original names. Add new functions, if any, to the Wrapper Class as needed.

The first option is relatively straightforward and easy to implement. However, we will choose the second option to learn how to access the Base Class’s properties within the new Wrapper Class and how to mask their original names with new property names.

The Transformed ClsVolume2 Class.

  1. Open your Database and display the VBA Editing Window (Alt+F11).

  2. Select the Class Module from the Insert Menu to insert a new Class Module.

  3. Change the Class Module’s Name property Value from Class1 to ClsSales.

  4. Copy and Paste the following VBA Code into the Module and Save the Code:

    Option Compare Database
    Option Explicit
    
    Private m_Sales As ClsVolume2
    
    Private Sub Class_Initialize()
        'instantiate the Base Class in Memory
        Set m_Sales = New ClsVolume2
    End Sub
    
    Private Sub Class_Terminate()
        'Clear the Base Class from Memory
        Set m_Sales = Nothing
    End Sub
    
    Public Property Get Description() As String
      Description = m_Sales.CArea.strDesc 'Get from Base Class
    End Property
    
    Public Property Let Description(ByVal strValue As String)
      m_Sales.CArea.strDesc = strValue ' Assign to Base Class
    End Property
    
    Public Property Get Quantity() As Double
    Quantity = m_Sales.CArea.dblLength
    End Property
    
    Public Property Let Quantity(ByVal dblValue As Double)
       If dblValue > 0 Then
         m_Sales.CArea.dblLength = dblValue ' Assign to clsArea, Base Class of ClsVolume2
       Else
         MsgBox "Quantity: " & dblValue & " Invalid.", vbExclamation, "ClsSales"
         Do While m_Sales.CArea.dblLength <= 0
              m_Sales.CArea.dblLength = InputBox("Quantity:, Valid Value >0")
         Loop
       End If
    End Property
    
    Public Property Get UnitPrice() As Double
       UnitPrice = m_Sales.CArea.dblWidth
    End Property
    
    Public Property Let UnitPrice(ByVal dblValue As Double)
       If dblValue > 0 Then
          m_Sales.CArea.dblWidth = dblValue ' Assign to clsArea, Base Class of ClsVolume2
       Else
         MsgBox "UnitPrice: " & dblValue & " Invalid.", vbExclamation, "ClsSales"
           Do While m_Sales.CArea.dblWidth <= 0
              m_Sales.CArea.dblWidth = InputBox("UnitPrice:, Valid Value >0")
           Loop
       End If
    End Property
    
    Public Property Get DiscountPercent() As Double
       DiscountPercent = m_Sales.dblHeight
    End Property
    
    Public Property Let DiscountPercent(ByVal dblValue As Double)
    ' Assign to Class .dblHeight of ClsVolume2
    Select Case dblValue
        Case Is <= 0
           MsgBox "Discount % -ve Value" & dblValue & " Invalid!", vbExclamation, "ClsSales"
           Do While m_Sales.dblHeight <= 0
              m_Sales.dblHeight = InputBox("Discount %, Valid Value >0")
           Loop
        Case Is >= 1
           m_Sales.dblHeight = dblValue / 100
        Case 0.01 To 0.75
           m_Sales.dblHeight = dblValue
    End Select
    End Property
    
    Public Function TotalPrice() As Double
    Dim Q As Double, U As Double
    Q = m_Sales.CArea.dblLength
    U = m_Sales.CArea.dblWidth
    If (Q * U) = 0 Then
       MsgBox "Quantity / UnitPrice Value(s) 0", vbExclamation, "ClsVolume"
    Else
       TotalPrice = m_Sales.CArea.Area 'Get from Base Class ClsArea
    End If
    End Function
    
    Public Function DiscountAmount() As Double
       DiscountAmount = TotalPrice * DiscountPercent
    End Function
    
    Public Function PriceAfterDiscount()
       PriceAfterDiscount = TotalPrice - DiscountAmount
    End Function
     

So far in the Wrapper Class, we have created an instance of the ClsVolume2 class, renamed its property and function members to more suitable names, and added validation checks with appropriate error messages. We also ensured that invalid input does not trigger the Base Class’s own validation routines, which could otherwise display error messages like “Value of the dblLength property is invalid” from the ClsVolume2 class.

Review the highlighted lines in the code above; they should help you understand how the property values are assigned to and retrieved from the Base Class ClsVolume2.

First, review the ClsArea Class Module, and then examine the ClsVolume2 Class Module, which is derived from ClsArea. After understanding both of these, revisit the code in this Wrapper Class for a better perspective.

Test Program for ClsSales Class in Standard Module.

Let us write a Test Program to try out the Wrapper Class.

  1. Copy and Paste the following VBA Code into a Standard Module.

    Public Sub SalesTest()
    Dim S As ClsSales
    
    Set S = New ClsSales
    
    S.Description = "Micro Drive"
    S.Quantity = 12
    S.UnitPrice = 25
    S.DiscountPercent = 0.07
    
    Debug.Print "Desccription", "Quantity", "UnitPrice", "Total Price", "Disc. Amt", "To Pay"
    With S
        Debug.Print .Description, .Quantity, .UnitPrice, .TotalPrice, .DiscountAmount, .PriceAfterDiscount
    End With
    End Sub

    Run The Code.

  2. Keep the Debug Window open (Ctrl+G).

  3. Click somewhere in the middle of the Code and press the F5 key to run the Code and to print the output in the Debug Window.

  4. You can further test the code by entering negative numbers for any of the input values and running it to trigger the new error messages. You may also try disabling one or more input lines by placing a comment symbol (') at the beginning of the line, then rerun the code and observe the results.

Calculate Price/Discount for an Array of Products.

The following test code creates an array of three Products and Sales Values by entering directly from the Keyboard. 

Copy and paste the following Code into a Standard Module and run to test the Wrapper Class further.

Public Sub SalesTest2()

Dim S() As ClsSales
Dim tmp As ClsSales
Dim j As Long

For j = 1 To 3
Set tmp = New ClsSales
   tmp.Description = InputBox(j & ") Description")
   tmp.Quantity = InputBox(j & ") Quantity")
   tmp.UnitPrice = InputBox(j & ") UnitPrice")
   tmp.DiscountPercent = InputBox(j & ") Discount Percentage")
 ReDim Preserve S(1 To j) As ClsSales
 Set S(j) = tmp
 Set tmp = Nothing
Next

'Output Section
Debug.Print "Desccription", "Quantity", "UnitPrice", "Total Price", "Disc. Amt", "To Pay"
For j = 1 To 3
   With S(j)
       Debug.Print .Description, .Quantity, .UnitPrice, .TotalPrice, .DiscountAmount, .PriceAfterDiscount
   End With
Next

For j = 1 To 3
  Set S(j) = Nothing
Next

End Sub

Once the correct values have been successfully entered into the array, the product names and corresponding sales values are displayed in the Debug Window.

CLASS MODULES.

Demo Database Download


  1. MS-Access Class Module and VBA
  2. MS-Access VBA Class Object Arrays
  3. MS-Access Base Class and Derived Objects
  4. VBA Base Class and Derived Objects-2
  5. Base Class and Derived Object Variants
  6. Ms-Access Recordset and Class Module
  7. Access Class Module and Wrapper Classes
  8. Wrapper Class Functionality Transformation

COLLECTION OBJECT.

  1. Ms-Access and Collection Object Basics
  2. Ms-Access Class Module and Collection Object
  3. Table Records in Collection Object and Form

DICTIONARY OBJECT.

  1. Dictionary Object Basics
  2. Dictionary Object Basics-2
  3. Sorting Dictionary Object Keys and Items
  4. Display Records from Dictionary to Form
  5. Add Class Objects as Dictionary Items
  6. Update Class Object Dictionary Item on Form
Share:

Base Class and Derived Object Variants

Introduction.

Last week, we explored an example where a Base Class Object was passed through a Set Property Procedure, allowing it to become part of another object in memory. The passed object essentially became an extension or child object of the main object. In that earlier program, we passed the child object to the target object during the instantiation phase of our test program and then assigned values to the child object’s properties later in the code.

In the next example, we will take a slightly different approach.

For those who would like to go through the earlier Articles on the MS-Access Class Module, the links are given below:

This time, we will open both objects—ClsArea (the base class) and ClsVolume2 (the target class)—separately in our test program. We will assign values to the ClsArea base class properties before passing it to the ClsVolume2 target class object. Remember, the ClsVolume2 class has only one property, p_Height, and its Volume() method requires the Length and Width values from the base class ClsArea to calculate the volume.

  1. Copy and paste the following sample Test Code into a Standard Module.

    The SetNewVol2_2 Procedure.

    Public Sub SetNewVol2_2()
    'Method 2/2
    Dim CA As ClsArea
    Dim Vol As ClsVolume2
    
    Set CA = New ClsArea
    Set Vol = New ClsVolume2
    
    CA.strDesc = "Bed Room"
    CA.dblLength = 90
    CA.dblWidth = 10
    Stop
    
    
    'Here ClsArea class Object CA is passed to the 
    ‘Property procedure Set CArea of ClsVolume2 object Vol
    Set Vol.CArea = CA 'Pass ClsArea obj to ClsVolume2
    
    Vol.dblHeight = 10 'assign height to ClsVolume2
    
    
    Debug.Print "Description", "Length", "Width", "Area", "Height", "Volume"
    With Vol.CArea
      Debug.Print .strDesc, .dblLength, .dblWidth, .Area(), Vol.dblHeight, Vol.Volume()
    End With
    Stop
    
    Set CA = Nothing
    Set Vol = Nothing
    
    End Sub
    

    VBA Code Review.

    In the first Dim statement, CA is declared as a ClsArea object and Vol as a ClsVolume2 object. The next two statements instantiate these objects in memory.

    The following three statements assign values to the properties of the ClsArea object.

    A Stop statement is then used to pause code execution, allowing us to inspect the property values of the object in the Locals window.

    Next, the statement Set Vol.CArea = CA assigns the ClsArea object (CA) as a child object of the ClsVolume2 object (Vol).

    After that, the dblHeight property of the ClsVolume2 object is assigned the value 10.

    The subsequent statements, placed before the next Stop statement, print the property values from memory to the Debug window.

    Finally, the last two Set statements release both objects from memory before the program ends.

    Display the Locals Window.

  2. Inspecting the Locals Window

    1. Open the Locals Window
      From the View menu in the VBA Editor, select Locals Window.

    2. Run the Code

      • Click anywhere in the middle of the code window.

      • Press F5 to run the program until it pauses at the Stop statement.

      • Alternatively, press F8 to run the code step by step, which lets you observe the changes in the Locals Window at each step.

    3. Expand the Objects
      Click the [+] symbol next to the object names in the Locals Window to expand and display their properties and current values.

    4. Observe Object References

      • Check the CArea and p_Area object references under the Vol object.

      • At this point, their values will show as Nothing because we have not yet passed the CA object to the Vol object.

    5. Continue Running the Code

      • After reviewing the Locals Window, run the code until it pauses at the next Stop statement.

      • Now, the CArea Set Property procedure assigns the p_Area object reference to the ClsArea object, linking it into the ClsVolume2 object.


    Next, we will try another variation of this example using the same two classes — ClsArea and ClsVolume2 — to demonstrate a slightly different approach.

New Class Module ClsVolume3.

1.  Insert a new Class Module and change its name Property Value to ClsVolume3.

2.  Copy and Paste the following VBA Code into the ClsVolume3 Class Module:

Option Compare Database
Option Explicit
'Method three 
Private p_Height As Double
Public p_Area As ClsArea

Public Property Get dblHeight() As Double
    dblHeight = p_Height
End Property

Public Property Let dblHeight(ByVal dblNewValue As Double)
    p_Height = dblNewValue
End Property

Public Function Volume() As Double
    Volume = p_Area.dblLength * p_Area.dblWidth * Me.dblHeight
End Function

Private Sub Class_Initialize()
    Set p_Area = New ClsArea
End Sub

Private Sub Class_Terminate()
    Set p_Area = Nothing
End Sub

In the code, p_Height is declared as private property, while p_Area is declared as a public ClsArea object within the ClsVolume3 class. This means p_Area appears as a property of the ClsVolume3 class, with its own accessible properties and methods for direct Get/Let operations in the user program (from a standard module). Although the ClsArea object is exposed as a public property of ClsVolume3, its internal properties and methods remain encapsulated within the ClsArea class itself.

It is important to ensure that the ClsArea class is fully developed and free of errors before using it inside other classes.

The Class_Initialize() and Class_Terminate() routines handle the lifecycle of the embedded object: The ClsArea object is instantiated in Class_Initialize() when a ClsVolume3 object is created, and released from memory in Class_Terminate() When the user program ends.

The Testing Program.

The sample Test VBA Code is given below.

Copy and paste the code into the Standard Module.

Public Sub SNewVol3()
'Here ClsArea class is declared as a Public Property of ClsVolume3
Dim volm As ClsVolume3

Set volm = New ClsVolume3

volm.p_Area.strDesc = "Bed Room"
volm.p_Area.dblLength = 15 'assign length
volm.p_Area.dblWidth = 10 'assign width in clsArea
volm.dblHeight = 10 'assign height to ClsVolume2

Debug.Print "Description", "Length", "Width", "Area", "Height", "Volume"
With volm.p_Area
   Debug.Print .strDesc, .dblLength, .dblWidth, .Area, volm.dblHeight, volm.Volume
End With
Set volm = Nothing

End Sub

Display the Locals Window (View -> Locals Window), if it is not already open.

Click somewhere in the middle of the code and press F8 to execute the VBA Code one line at a time and watch the Local Window to track what happens at each step.

All the above variants of the ClsVolume Class have been written with less Code, except the first example of the ClsVolume Class.  

Working with the Recordset Object.

Next week, we will work with a built-in Object 'DAO.Recordset' and build a Class Module to:

  1. Calculate and update a Field,

  2. Sort the Data,

  3. Print the sorted data in the Debug Window,

  4. And create a Clone of the Table with sorted data.

That is a lot of action next week.

List of All the Links on this Topic.

Earlier Post Link References:

  1. MS-Access Class Module and VBA
  2. MS-Access VBA Class Object Arrays
  3. MS-Access Base Class and Derived Objects
  4. VBA Base Class and Derived Objects-2
  5. Base Class and Derived Object Variants
  6. Ms-Access Recordset and Class Module
  7. Access Class Module and Wrapper Classes
  8. Wrapper Class Functionality Transformation
  9. Ms-Access and Collection Object Basics
  10. Ms-Access Class Module and Collection Object
  11. Table Records in Collection Object and Form
  12. Dictionary Object Basics
  13. Dictionary Object Basics-2
  14. Sorting Dictionary Object Keys and Items
  15. Display Records from Dictionary to Form
  16. Add Class Objects as Dictionary Items
  17. Update Class Object Dictionary Item on Form

Share:

VBA Base Class and Derived Object-2

Introduction.

Last week, we created a derived Class, 'lsVolume', using ClsArea as the base class. In that approach, we added property procedures in the derived class to expose the base class’s properties and functions to the user programs. This method, however, requires repeating all the base class property procedures in the derived class.

In this section, we will explore how to create the same derived ClsVolume class without duplicating the property procedures of the ClsArea base class.

So far, we have learned about Get and Let property procedures in classes. There is also a third type: the Set Property Procedure, which is used to directly assign an object to a class object of the same type.

Before proceeding, you may want to revisit the earlier pages on this topic if you haven’t already. Links are provided below:


ClsVolume Class, the Makeover.

We shall create a different variant of the same ClsVolume Class Module we created last week, using ClsArea as Base Class, with a different approach, and with less Code. 

Create a new Class Module and change its Name Property Value to ClsVolume2.

Copy and Paste the following Code into the Class Module ClsVolume2 and Save the Module:

Option Compare Database
Option Explicit
'Method two-1
Private p_Height As Double
Private p_Area As ClsArea

Public Property Get dblHeight() As Double
    dblHeight = p_Height
End Property

Public Property Let dblHeight(ByVal dblNewValue As Double)
    p_Height = dblNewValue
End Property

Public Function Volume() As Double
    Volume = p_Area.dblLength * p_Area.dblWidth * p_Height
End Function

The new Get and Set Property Procedure for the ClsArea Object.

Public Property Get CArea() As ClsArea
   Set CArea = p_Area
End Property

Public Property Set CArea(ByRef AreaValue As ClsArea)
  Set p_Area = AreaValue
End Property

From the Debug menu, select Compile [Project Name] to compile all the VBA code in your database and ensure it is error-free. If any errors are found in other VBA programs, locate and correct them, then recompile the project.

While unresolved errors will not prevent you from assigning or retrieving values from object properties, the VBA IntelliSense—which displays a list of an object’s properties and functions—will not work properly until the project compiles successfully.

Seeing the property list appear in IntelliSense is an invaluable aid during coding, especially while learning and experimenting with class objects.


Get / Set instead of the Get / Let Property Procedure.

In this version of the ClsVolume class, we have omitted all the property procedures  ClsArea that were present in the previous version. Instead, we use Get and Set property procedures rather than the traditional Get/Let pair.

Take a look at the declaration: the private member p_Area is declared as a ClsArea class object. Normally, when an object is declared this way, we would create an instance of it in the Class_Initialize() procedure.

However, in this approach, we have not instantiated it within the class. The plan is to create and populate the ClsArea object in the user program, set its properties with appropriate values, and then pass it to the ClsVolume2 class. The class will then use these values during the final calculation phase.

Take note of the Set CArea() procedure. Its ByRef parameter, AreaValue, is declared as a ClsArea object. When an ClsArea instance is passed to this property procedure, the object variable AreaValue receives it and assigns it to the private p_Area property of the ClsVolume2 object.

This mechanism allows the ClsVolume2 class to use an externally created and populated ClsArea object without having to instantiate it internally, maintaining flexibility and reusability.

The Get CArea() Property procedure returns the Object to the calling program.

In our earlier programs, we wrote property procedures for individual elements of an object, such as Length, Width, and Height—to assign or retrieve values. In this version, the difference is that we are passing an entire object as a parameter to a Set property procedure.

To access a property of this passed object—for example, dblLength—we use the syntax CArea.dblLength. Here, the Get/Set property procedure name CArea essentially becomes a child object of the main object when declared in the main program. Its individual properties can then be accessed directly using the object address, such as:

Vol.CArea.dblLength

This approach allows the main object to interact with the entire child object and its properties as a single unit, simplifying property management and enhancing reusability.

A Test Program in Standard Module.

We will now create a small test program in a Standard Module to verify the functionality of our newly derived class object. ClsVolume2.

  1. Insert a new Standard Module into your project.

  2. Copy and paste the following code into the module.

  3. Save the module before running the program.

Public Sub SetNewVol2_1()
'Method 1/2
Dim Vol As New ClsVolume2

'ClsArea Object instantiated and passed to the
'Property Procedure Set CArea in ClsVolume2.

Set Vol.CArea = New ClsArea 'declare and instantiate the object in one statement

Stop

Vol.CArea.strDesc = "Bed Room"
Vol.CArea.dblLength = 90
Vol.CArea.dblWidth = 10

Vol.dblHeight = 10 'assign height to ClsVolume2

Stop

Debug.Print "Description", "Length", "Width", "Area", "Height", "Volume"
Debug.Print Vol.CArea.strDesc, Vol.CArea.dblLength, Vol.CArea.dblWidth, Vol.CArea.Area, Vol.dblHeight, Vol.Volume

Set Vol.CArea = Nothing
Set Vol = Nothing

End Sub

Code Review Line by Line.

Let’s quickly review the VBA code above.

  1. The first line instantiates the ClsVolume2 class with the object name Vol.

  2. After the comment lines, the Set Vol.CArea statement calls the property procedure and passes the newly instantiated ClsArea object as its parameter.

I included a Stop statement on the next line to pause the program so you can observe how the object is assigned to the CArea property. We’ll explore how to inspect this in memory shortly.

  1. The following four lines assign values to the ClsArea object properties (strDesc, dblLength, dblWidth) and to the dblHeight property of the ClsVolume2 object.

  2. The next Stop statement pauses the program again, allowing you to inspect how these values are stored in memory.

  3. The subsequent line prints the headings in the Debug Window for clarity.

  4. Finally, the last line prints the values of the object properties retrieved from memory, displaying them in the Debug Window.

Run the Code to the Next Stop Statement

  1. Let’s run the code and inspect the memory to see what happens at each stage where the Stop statements are placed.

    1. Click anywhere inside the code and press F5 to run the program. The execution will pause at the first Stop statement.

    2. From the View menu, select Locals Window. This opens a window below the code editor that displays the ClsArea and ClsVolume2 objects, along with their properties and member procedures, as they are stored in memory.

    3. Observe the structure of the objects and how the property values are held. A sample image of the Locals Window is shown below for reference.

    The Locals Window View.


    To give more space for the Locals Window, drag the sizing handles of other windows upward to reduce their height. Alternatively, you can close the Debug Window temporarily and press Ctrl+G to bring it back when needed.

    The Locals Window provides a graphical view of all objects and their properties in memory:

    1. The first item with a plus [+] symbol shows the name of the Standard Module from which the program is running.

    2. The next plus [+] symbol represents the Vol object, which is the instantiated ClsVolume2 object in memory.

    Click the plus [+] symbols to expand each item and display detailed information about the object’s properties and member procedures.

    You will find the next level of Objects and Properties.

    The [+]CArea indicates that this Object has the next level of Properties and their Values.

    The dblHeight Get property Procedure comes directly under the Vol Object.

    The [+]p_Area is the Private Property declared ClsArea Class in the ClsVolume2 Class.

    The p_Height is also the Private Property declared in the ClsVolume2.

    Click on the plus [+] symbols to expand the objects to show their Properties and Values.

    Expanding the [+] CArea node displays the ClsArea object that was passed to the Set CArea() property procedure.

    The expansion of [+]p_Area gives the view of the ClsArea Property declared as Private.

    Note that the p_Area Private Property, of the ClsVolume2 Class Object, and all its elements are accessible only through the CArea Object Property Get/Set Procedures to the outside world.

    The second column in the Locals Window displays the values assigned to the object’s properties. At this stage, no values have been assigned, so the fields are currently empty.

    The Third Column shows the Data Type or Object Class Module Names.

    Press F5 to run the program further, till it is paused at the next Stop statement, to assign some values to the Object Properties.  The program will pause at the next Stop statement.  Check the Locals Window for changes in Values.

    Inside the CArea Object, the first two lines with values 90, 10, and the last strDesc Variable with value "Bedroom" are assigned through the Get Property Procedures, respectively. The p_Desc, p_Length, and p_width are values assigned through Set Property Procedures to the p_Area Property of the ClsVolume2 Class Object as well.

    The p_Area Object of ClsArea Class declared as Private Property of ClsVolume2 is seen with its Get/Set Property Procedures and assigned values.

    Check the Type Column of [-]CArea and [-]p_Area; both Objects are derived from the ClsArea Base Class.

    Usage of ClsArea and ClsVolume2 Class Objects Differently.

    Next week, we will explore another approach using the same two objects.

    If you’d like to experiment on your own beforehand, here’s a clue to get you started:

    1. Instantiate ClsVolume2 and ClsArea classes as two different Objects in the Standard Module Program.

    2. Assign values to both Object Properties.

    3. Assign the ClsArea instantiated Object to the CArea Object in the ClsVolume2 Class Object, before printing the Values to the Debug Window.

    In this example, we can achieve the same result as in the previous example without having to repeat the Get/Let property procedures in the ClsVolume class module.

    The Links of All the Pages in this Topic.

    1. MS-Access Class Module and VBA
    2. MS-Access VBA Class Object Arrays
    3. MS-Access Base Class and Derived Objects
    4. VBA Base Class and Derived Objects-2
    5. Base Class and Derived Object Variants
    6. Ms-Access Recordset and Class Module
    7. Access Class Module and Wrapper Classes
    8. Wrapper Class Functionality Transformation
    9. Ms-Access and Collection Object Basics
    10. Ms-Access Class Module and Collection Object
    11. Table Records in Collection Object and Form
    12. Dictionary Object Basics
    13. Dictionary Object Basics-2
    14. Sorting Dictionary Object Keys and Items
    15. Display Records from Dictionary to Form
    16. Add Class Objects as Dictionary Items
    17. Add Class Objects as Dictionary Items
    18. Update Class Object Dictionary Item on Form

Share:

Opening Multiple Instances of Form in Memory

Introduction.

For the last few weeks, we have been through learning the usage of dot (.) separator and exclamation symbol (!) in VBA object references.  Now, we will explore some interesting tricks with Forms in VBA.  How to Call a Function Procedure embedded in a Form Module (Class Module), from a program outside the Form?

We will explore two different aspects of this particular topic.

  1. How do we open several instances of a single Microsoft Access Form in memory, displaying different information on each of them?

    A sample screenshot of two instances of the Employees Form is given below for reference.  The first form is behind the second instance of the form, displaying employee details of ID: 4 & 5.   Click on the image to enlarge the picture. 


    Calling the Form's Class Module Public Function.

  2. How to call a Function Procedure on the Form's Class Module, from outside the Form?

    Call the Function from a Standard Module,  from the Module of another form, or from the VBA Debug Window (Immediate Window).  The target form must be opened in memory in order to call the function procedure of the form from outside.

Function Procedures in a Form module are helpful to avoid duplication of code. It can be called from subroutines in different locations on the same Form, from a command button click, or from some other Event Procedures of the Form.  The function procedure in a Form Module can be anything that does some calculation, validation check, updating the information, or a stand-alone search operation procedure, like the one we are going to use on our sample Employees Form.

All the Event Procedures on a Form Module are automatically declared as Private Subroutines and they all will start with the beginning and end Statements, like the sample statements given below.   Our own VBA code that does something will go within this block of codes:

Private Sub Command8_Click()
.
.
End Sub

The scope of Private declared Subroutine/Function stays within that module and cannot be called from outside.  The private declaration is absolutely necessary to avoid a procedure name clash with the same name in another Class Module or Standard Module.  The Form's Function Procedure must be declared as Public in order to call it from outside the Form.

To perform a trial run of the above trick you need the Employees Table and a Form.

  1. Import Employees Table from Northwind sample database.
  2. Click on the Employees Table to select it.
  3. Click on Create Ribbon.
  4. Select the Form option and create a Form, for Employees Table, in the format shown above.
  5. Save the Form with the name frmEmployees.
  6. Open the frmEmployees Form in Design View.  Set the Form Property Has Module Value to Yes.
  7. Select the Design Menu and select VBA Code from the Tools button group, to open the Form Module.
  8. Copy the following VBA code and Paste them into the VBA Module of the Form.

    Public Function in Form ClassModue.

    Public Function GetFirstName(ByVal EmpID As Integer) As String
    Dim rst As Recordset, crit As String
    Dim empCount As Integer
    
    'get total count of employees in the Table
    empCount = DCount("*", "Employees")
    
    'validate employee code
    If EmpID > 0 And EmpID <= empCount Then
    
        crit = "ID = " & EmpID
        Set rst = Me.RecordsetClone
        rst.FindFirst crit
        
        If Not rst.NoMatch Then
              
         	Me.Bookmark = rst.Bookmark
            GetFirstName = rst![First Name]
        End If
        
           rst.close
           Set rst = Nothing
        
      Else
        MsgBox "Valid Employee IDs: 1 to " & empCount
    End If
    
    End Function
    
  9. Save and Close the Form.

Have you noticed the starting line of the above Function, which is declared as Public?

The Function GetFirstName() accepts a parameter EmployeeID value, finds that record and will make that record current on the form. The Function returns the First Name of the Employee to the calling program if the search was successful.  If the search operation fails, then it gives a warning message, saying that the employee ID code passed to the function is not within the range of ID codes available in the Employees table.

Now, we need another program, in the Standard Module, to run the search function GetFirstName() from the frmEmployees Form Module.  Besides that this program demonstrates how to create more than one instance of a Microsoft Access Form and open them in memory, to access their properties, methods, or control contents.

  1. Open VBA Editing Window (Alt+F11).
  2. Select the Module option from Insert Menu and add a new Standard Module.
  3. Copy and paste the following VBA Function code into the new Module.

    Call GetFirstName() from Standard Module.

    Public Function frmInstanceTest()
    
          Dim frm As New Form_frmEmployees '1st Form instance
    
          Dim frm2 As New Form_frmEmployees '2nd instance declaration
    
          Dim Name1 As String, Name2 As String
    
      frm.Visible = True 'make the instance visible in Application Window
      frm2.Visible = True '2nd instance visible
    
      Name1 = frm.GetFirstName(4) 'Call the GetFirstName of Employee ID 4
      
      Name2 = frm2.GetFirstName(5) ''Call the GetFirstName of Employee ID 5
    
    'pause execution of this code to view
    'the Employees Form instances in Application Window.
    
    Stop
    
      MsgBox "Employees " & Name1 & ", " & Name2
      
    End Function

Trial Run of Function frmInstanceTest()

Let us run the code and view the result in Application Window.

  1. Click somewhere within the body of the frmInstanceTest() function and press the F5 key to run the code.

    The program will pause at the Stop statement and this will facilitate the viewing of the Application window, where the frmEmployees Form instances are open in normal view mode, one overlapping the other.

  2. Press Alt+F11 to display the Application Window displaying both instances of the Form, the second form overlapping the first one.
  3. Click and hold on to the title bar area of the top form and drag it to the right, to make part of the form behind visible.

    Check the employee records on both forms, they are different, one with employee code 4 and the other is 5.  Check the title area of the forms, both are showing frmEmployees titles.  Now, let us come back to the program and continue running the code to complete the task.

  4. Press Alt+F11 again to switch back to the VBA Window and press the F5 key one more time to continue executing the remaining lines of code.

    The Message Box appears in the Application Window displaying the Employee names Mariya and Steven together.  When you click the OK MsgBox Button, the frmEmployee form instances disappear from the Application Window.

  5. Click the OK button on the MsgBox.

Note: I would like to draw your attention to the Stop statement above the MsgBox() function, at the end part of the code. The Stop statement pauses the execution of the VBA code on that statement.  Normally, this statement is used in a program for debugging code, to trace logical errors and corrections.  Here, it is required to pause the execution of code so that we can go to the Application Window and view both instances of the frmEmployees Form there.  The MsgBox() will pause the code, but we will see only the topmost instance of the form. We cannot drag the top form to the right side while the MsgBox is displaced.

If we don't create a pause in the code execution, both instances of the form are closed immediately, when the program ends.  In that case, we will not be able to view the forms.  Since it is a trial run we would like to know what is happening in the program. It is not necessary to make the Form instances visible, before calling the Function GetFirtName().

The VBA Code Line by Line.

Let us take a closer look at each line of code of the frmInstanceTest() function.  Even though hints are given on each line of code, explaining a few things here will make them more clear to you.  We will start with the first two Dim Statements.

Dim frm As New Form_frmEmployees
Dim frm2 As New Form_frmEmployees

In the above Dim statement, you can see that the New keyword is followed by the object reference. The object name is our frmEmployees prefixed by the direct Object Class name FORM followed by an underscore character separation (Form_) to the frmEmployees Form name (Form_frmEmployees).  These Dim statements themselves open two instances of the frmEmployees in memory.   Form instances opened in this way are not immediately visible in the Application Window.  If we need them to be visible, then make them visible with another statement.

Next, we declared two String Variables: Name1 & Name2 to hold the names returned by the GetFirstName() method.

Next two statements: frm.Visible=True and frm2.Visible=True, makes both instances of the frmEmployees Form visible in the Application Window, for information purposes only.

In the next two lines of code, we are calling the GetFirstName() method of the first and second instances of the frmEmployees to search, find and return the First Names of employee codes 4 and 5.

Default Instance and Other Instances.

The default instance of a Form is opened, in the following manner in programs, for accessing their Properties, Methods, and Controls.  These styles of statements are always used to open a form in programs. The default instance of the Form will be automatically visible, in the Application Window.

Dim frm as Form 'define a Form class object
DoCmd.OpenForm "frmEmployees", vbNormal 'open frmEmployees in Memory
Set frm3 = Forms!frmEmployees ' attach it to the frm3 object

Assume that we have opened frm & frm2 instances first in memory before the default instance through the above code.  How do we address those three instances in a program to do something?  Let us forget about the frm, frm2, frm3 object references, for now, we will go with the straight method, like the one given below:

name3 = Forms![frmEmployees].GetFirstName(5) 'target form in memory is the default instance
'OR
name3 = Forms("frmEmployees").GetFirstName(5) 
'OR
name3 = Forms(2).GetFirstName(5) ' this is the third and default instance

The other two instances in memory cannot be referenced like the first two default methods, using the name of the form. You have to use only the index number of the Forms collection to address the other two instances.

name1 = Forms(0).GetFirstName(3)
name2 = Forms(1).GetFirstName(6)

A Shortcut Method.

There is a shortcut method you can use to run the GetFirstName() Method of the frmEmployees Form from the debug window (Ctrl+G).  Type the following command on the Debug Window and press Enter Key:

? form_frmEmployees.GetFirstName(5)
'Result: Steven
'OR
X = form_frmEmployees.GetFirstName(5)

What happens when we execute the above command?  It opens an instance of the frmEmployees in memory, Calls the Function GetFirstName() with the employee Code 5. The GetFirstName() runs and finds the record and returns the First Name of the employee and closes the form.

Tip: Even after closing the Form, after the execution of the above command, the current record, of Employee ID 5, remains as current on the closed Form.

You can check this by executing the following shortcut command by typing it in the debug window and pressing Enter Key.

? form_frmEmployees![First Name]
'Result: Steven

A Fancy Approach.

In the above command, we didn't run the GetFirstName() method, but the current record's First Name field value is printed. If you want to get a little fancy with the command, then try this by typing it in the debug window and pressing the Enter Key:

MsgBox "First Name: " & form_frmEmployees.GetFirstName(8)
'OR
MsgBox "First Name: " & form_frmEmployees![First Name]

Or try the above command from a Command Button Click Event Procedure from another Form's Module, as given below.

Private Sub Command8_Click()
  MsgBox "First Name: " & Form_frmEmployees.GetFirstName(8)

End Sub
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