Learn Microsoft Access Advanced Programming Techniques, Tips and Tricks.

Monday, June 20, 2011

Change Query Top Values Property with VBA

Introduction.

We have already learned how to use the Top Values property of Queries (applicable in SELECT, MAKE-TABLE, and APPEND queries) in an earlier post. If you haven’t seen it yet, I recommend taking a look at that article first [link here].

The Top Values property of a Query can only be set manually during design time. Unfortunately, you cannot directly change its value dynamically in VBA. You also cannot expect users to open the query in Design View each time they want a different set of results.

So, how do we handle situations where we need flexibility with these values?

Sample SQL with TOP Property Setting.

When we change the Top Values property manually, Microsoft Access automatically updates the SQL statement of the Query to reflect that change. Keeping this behavior in mind, we can use a little VBA trickery to manipulate the SQL directly, rather than searching for a property setting that doesn’t exist.

Before we move on to that approach, let us first examine what actually happens to the SQL definition of a Query when you set the Top Values property or other related properties.

Here is a sample SQL of a SELECT Query with the Top Values-Property set to the Value 25.

SELECT TOP 25 Orders.OrderID, Orders.EmployeeID, Orders.OrderDate, Orders.RequiredDate, Orders.Freight
FROM Orders
ORDER BY Orders.Freight DESC;

As shown in the example, when the Top Values property is set to 25, Access automatically inserts the text TOP 25 immediately after the SELECT clause in the SQL string. This indicates that the Query will return only 25 records. In the ORDER BY clause, the Freight column is sorted in descending order, so the output consists of the 25 records with the highest freight values in the table.

If, instead of a fixed number of records, you want a percentage of the total records—for example, 25%—then the Top Values property must be set to 25% rather than 25. In this case, the SQL text changes accordingly to:

SELECT TOP 25 PERCENT Orders.OrderID, Orders.EmployeeID, Orders.OrderDate, Orders.RequiredDate, Orders.Freight
FROM Orders
ORDER BY Orders.Freight DESC;

The next property that affects the record set is the Unique Values property (valid values: Yes or No). When this property is set to Yes, Access suppresses duplicate records in the output shown in the datasheet. However, it only evaluates the fields included in the Query’s column list—other fields from the table that are not selected are ignored when checking for duplicates.

When this property is enabled, Access inserts the keyword DISTINCT in the SQL, immediately after the SELECT clause. The modified SQL will look like this:

SELECT DISTINCT TOP 25 PERCENT Orders.OrderID, Orders.EmployeeID, Orders.OrderDate, Orders.RequiredDate, Orders.Freight
FROM Orders
ORDER BY Orders.Freight DESC;

Another property you can set in a query is Unique Records (valid values: Yes or No). When this property is set to Yes, Access suppresses duplicate records in the output. Unlike the Unique Values property, this setting evaluates all fields in the source table, regardless of whether they are included in the query’s column list.

When enabled, the SQL changes by replacing the DISTINCT keyword with DISTINCTROW. This ensures that the uniqueness check is applied across the entire underlying table.

For example:

SELECT DISTINCTROW TOP 25 PERCENT Orders.OrderID, Orders.EmployeeID, Orders.OrderDate, Orders.RequiredDate, Orders.Freight FROM Orders ORDER BY Orders.Freight DESC;

We will exclude the Unique Records property from our VBA-based solution. As shown in the examples above, depending on the user’s requirements, we can dynamically add or remove any of these three elements—DISTINCT, TOP n, or PERCENT—to control the query output for reports.

Preparing for the VBA-based Solution.

Our methodology for modifying the SQL is straightforward. We will collect the required Query property values from the user through a TextBox and a Checkbox placed on a Form. Once the user provides the input and clicks a Command Button, the SQL of the Query will be redefined accordingly. This will invoke the following actions to redefine the Query:

  1. Open the Query Definition and read the existing SQL String.

  2. Scan the SQL string and look for the text DISTINCT, TOP nn, and PERCENT.  If found, then remove them from the SQL String.

  3. Validate the input given by the User in the Textbox and checkbox, and insert appropriate SQL Clauses in the SQL String.

  4. Update the modified SQL in the Query definition.

This article has become too long now.  Explaining the above four steps and introducing the VBA Routines may make it even longer.  We will complete this topic in the next blog post.

Earlier Post Link References:


Wednesday, June 8, 2011

Creating Animated Command Button with VBA

Introduction.

My very first blog post on this website, published back in September 2006, was about the Command Button Animation method. I have used this technique in almost all of my projects since then. The animated response of command buttons to mouse movements gave the Forms a sense of life, making them feel interactive rather than rigid and boring.

The design involves creating a Command Button, along with a Rectangle control set with a shadow special effect, both placed manually. The animation itself is handled through Mouse_Move() event procedures written in the Form module, which call a common function to perform the animation.

If you haven’t read that post yet, I recommend reviewing it first to get a general understanding before continuing. [Click here to go to the earlier article.]

Now, let’s take this a step further and see how to create animated command buttons automatically, with their corresponding animation procedures written into the Form module, all at design time, with just a single click of a button.

Animated Button Creation Code.

With two VBA routines, we can do this very easily.

  1. Open one of your databases.

  2. Display the Standard VBA Module.

  3. Create a new Standard Module (Insert -> Module).

  4. Copy both the following Functions into the Standard Module and save the code:

Command Button Animation Code:

Public Function BAnimate(ByVal strForm As String, ByVal mode As Integer, ByVal lblName As String)
'---------------------------------------------------------------------------
'Author : a.p.r. pillai
'Date   : July 1998
'Remarks: Animates the Command Button
'Rights : All Rights Reserved by www.msaccesstips.com
'---------------------------------------------------------------------------
Dim Frm As Form, l As Long, t As Long

On Error GoTo BAnimate_Err

Set Frm = Forms(strForm)

l = Frm.Controls(lblName & "Box").Left
t = Frm.Controls(lblName & "Box").Top

If (mode = 1) And (Frm.Controls(lblName & "Box").Visible = False) Then
    Frm.Controls(lblName & "Box").Visible = True
        Frm.Controls(lblName).Left = l - (0.0208 * 1440)
        Frm.Controls(lblName).Top = t - (0.0208 * 1440)
        Frm.Controls(lblName).FontWeight = 700
ElseIf (mode = 0) And (Frm.Controls(lblName & "Box").Visible = True) Then
    Frm.Controls(lblName & "Box").Visible = False
        Frm.Controls(lblName).Left = l
        Frm.Controls(lblName).Top = t
        Frm.Controls(lblName).FontWeight = 400
End If

BAnimate_Exit:
Exit Function

BAnimate_Err:
Err.Clear
Resume BAnimate_Exit

End Function

Animated Command Button Creation Code:

Public Function CreateButton(ByVal intSection As Integer, strName As String)
'---------------------------------------------------------------------------
'Author : a.p.r. pillai
'Date   : Aug. 2000
'Remarks: Creates animated command button controls and Programs on a Form
'       : at design time of the form.
'Rights : All Rights Reserved by www.msaccesstips.com
'---------------------------------------------------------------------------
'Program Parameter Values : intSection
'     0 =  Form Detail Section
'     1 =  Form Header Section
'     2 =  Form Footer Section
'                         : strName
'Command Button Name Property Value
'The Name will be prefixed with the text 'cmd'
'Example: Edit will be modified as cmdEdit
'Sample Run : CreateButton 0,"Edit"
'Remarks    : If more than one Form is opened in Design View then the
'           : Command Button will be created on the first Form
'---------------------------------------------------------------------------
Dim Frm As Form, Ctrl As Control, txt As String
Dim vLeft As Long, vTop As Long, vWidth As Long, vHeight As Long
Dim i As Long, dif As Double, x As Long, Y As Long, z
Dim frmViewStatus As Integer, frmsCount As Integer, j As Integer
Dim hfd As String
On Error Resume Next

i = 1440
dif = 0.0208 * i
vLeft = 0.25 * i
vTop = 0.0521 * i
vWidth = 1.25 * i
vHeight = 0.2375 * i

frmsCount = Forms.Count - 1
frmViewStatus = False
For j = 0 To frmsCount
    If Forms(j).CurrentView = 0 Then
      Set Frm = Forms(j)
      frmViewStatus = True
      Exit For
    End If
Next
If frmViewStatus = False Then
   MsgBox "Open a Form in Design View then try again." & vbCr & vbCr & "Program CreateButton() Aborted."
   Exit Function
End If

  Set Ctrl = CreateControl(Frm.Name, acRectangle, intSection, , , vLeft, vTop, (vWidth - dif), (vHeight - dif))
  
  With Ctrl
    .Name = "cmd" & strName & "Box"
    .SpecialEffect = 4
    .BorderWidth = 3
  End With

  Set Ctrl = CreateControl(Frm.Name, acCommandButton, intSection, , strName, vLeft, vTop, vWidth, vHeight)
  
  With Ctrl
    .Name = "cmd" & strName
    .Caption = strName
  End With
   
  x = Frm.Module.CreateEventProc("MouseMove", Ctrl.Name)
  
  txt = "BAnimate me.name, 1, " & Chr(34) & "cmd" & strName & Chr(34)
  Frm.Module.InsertLines x + 1, txt

  hfd = Choose(intSection + 1, "Detail", "FormHeader", "FormFooter")

  z = Frm.Module.ProcBodyLine(hfd & "_MouseMove", vbext_pk_Proc)

  If z = 0 Then
      x = Frm.Module.CreateEventProc("MouseMove", hfd)
  Else
      x = z + 1
  End If

  txt = "BAnimate me.name, 0, " & Chr(34) & "cmd" & strName & Chr(34)
  Frm.Module.InsertLines x + 1, txt


CreateButton_Exit:
Exit Function

CreateButton_Err:
Resume CreateButton_Exit
End Function

Press Ctrl+S to save the programs. Keep the VBA Window open.

Do the Test Run.

Now that you have the main functions for creating and animating Command Buttons, let us do a quick run to see how easy it is.

  1. Close all open forms, if any.

  2. Open a new Form in Design View.

  3. Display the VBA window, if it was closed or minimized (Alt+F11).

  4. Display the Debug Window (Immediate Window) - Ctrl+G.

  5. Type the following statement in the Debug Window and press Enter Key:

    CreateButton 0, "Edit"
    • The first parameter value (0) represents the section of the form where the command button will be placed.

      • 0 = Detail Section

      • 1 = Form Header

      • 2 = Form Footer

    • The second parameter ("Edit") serves two purposes: it defines the command button’s Name (which will be modified to cmdEdit and assigned to the Name property) as well as its Caption.

      ⚠️ Important: The second parameter must always be a single word. This is essential for correctly creating the MouseMove event procedure in the form’s module. Once the button is created, you can always change its Caption later if needed.

  6. Minimize the VBA window to show the Form in Design View.  You can see the Command Button is created in the Detail Section of the Form with the Caption Edit.

  7. Change the Form into Form View.

  8. Move the Mouse over the Command Button.  The button moves up a little and to the left to show a shadow at the bottom and to the right of the Command Button.

  9. Move the mouse out of the button.  The Command Button settles back to the original position, hiding the shadow.

  10. Repeat this action in quick succession.  You can see the movement of the button more clearly.

    The VBA Code is Written by the Program.

    If you display the Form's VBA Module, you can see that the following VBA Program lines are written into it:

    Private Sub cmdEdit_MouseMove(Button As Integer, Shift As Integer, X As Single, Y As Single)
         BAnimate Me.Name, 1, "cmdEdit"
    
    End Sub
    
    Private Sub Detail_MouseMove(Button As Integer, Shift As Integer, X As Single, Y As Single)
        BAnimate Me.Name, 0, "cmdEdit"
    
    End Sub
  11. Change the Form mode to Design View again.

  12. Click on the Command Button to select it.

  13. Drag the Command Button to the right and down to show the Rectangle Control with the special effect shadow underneath it.

    The Command Button and the Rectangle Control work together to create the animation effect. To move them as a pair, click near the command button and drag the mouse over both controls to select them together. Then, drag the selection to the desired location on the form.

    It is important to do this before creating another command button in the same form section. Otherwise, the new button will be placed directly on top of the previous one. By default, all newly created command buttons are positioned in the same location within their section.

  14. Right-click on the Detail Section of the Form and select Form Header/Footer to display them on the Form.

Creating a Button on the Header or Footer Section.

You can now try the CreateButton() function with the first parameter set to 1 or 2 to create command buttons in the Form Header or Form Footer sections, respectively.

The second parameter, which specifies the name of the command button, must be unique for each button on the same form.

Below are sample statements demonstrating how to create animated command buttons on the header and footer sections of the form:

CreateButton 1, "PrintPreview"

CreateButton 2, "Exit"

Note: Make sure the Header and Footer sections are visible before attempting to create command buttons on them.

Also, ensure that only one form is open in Design View. If multiple forms are open, the first form found in design mode will be selected for creating the button controls.

During the form design time, running the CreateButton() function from the Debug Window is the most convenient method.

However, if you prefer a different approach, such as launching the program from a Command Button click, that can also be implemented easily.

Button Creation from a Command Button Click.

We can create a Command Button on a form that, when clicked, allows you to input parameter values for the button creation program. This will quickly create the new button on the form currently in Design View and automatically generate its associated Sub-Routines in the form’s module.

  1. Open a new Form in Design View.

  2. Create a Command Button as you normally do.

  3. Display its Property Sheet when the Command Button is in the selected state (F4).

  4. Change the Name property value to cmdCreate and set the Caption property value to Create Button.

  5. Display the Form's VBA Module (Alt+F11).

  6. Copy and paste the following Code into the Module and press Ctrl+S to save the Form with the name frmCreateButton:

    Private Sub cmdCreate_Click()
    Dim intSection As Integer, strButtonName As String
    Dim msg As String
    msg = "Form Section (0,1 or 2)" & vbCr
    msg = msg & "0 - Form Details" & vbCr
    msg = msg & "1 - Form Header" & vbCr
    msg = msg & "2 - Form Footer"
    
    intSection = 3
    Do While intSection < 0 Or intSection > 2
        intSection = Nz(InputBox(msg, "cmdCreate_Click()"), 0)
    Loop
    
    strButtonName = ""
    Do While Len(strButtonName) = 0
        strButtonName = InputBox("Command Button Name", "cmdCreate_Click()")
    Loop
    
       If (intSection >= 0 And intSection < 3) And Len(strButtonName) > 0 Then
           CreateButton intSection, strButtonName
       End If
    
    End Sub

    Perform a Demo Run

  7. Open a form in Design View and display the Form’s Header/Footer Sections.

  8. Open the frmCreateButton in Normal View.

  9. Click on the Command Button to enter the parameter values of the program.

  10. Input one of the values (0, 1, or 2) suggested by the Prompt to select a Section of the Form and press the Enter Key or click the OK button.

  11. Enter a Name for the Command Button in the second prompt (it should be a single word like PrintPreview) and press Enter Key or Click OK.

  12. The Command Button controls are created on the selected Section of the form you kept open in the design view.

    If you want to use this method across all your projects, you can transfer the first two functions, BAnimate() and CreateButton(), into a common Library Database. Then, attach this library as a Reference Library File to your projects. (Refer to the blog post Command Button Animation to learn how to do this.)

  1. Command Button Animation
  2. Double Action Command Button
  3. Colorful Command Buttons
  4. Transparent Command Button
  5. Command Button Animation-2
  6. Creating an Animated Command Button with VBA
  7. Command Button Color Change on Mouse Move

Powered by Blogger.