Learn Microsoft Access Advanced Programming Techniques, Tips and Tricks.

Macros and Temporary Variables

Introduction.

If you are using Microsoft Access 2007 or a later version of Access then there is something new for you. You can use the SetTempVar action in Macros to define Global Variables.  After that, you can use the values in those variables in another macro or in an event procedure, or on the Form or Report. The temporary variables remain in memory till you clear them with the RemoveTempvar macro action or remove all the variables with RemoveAllTempVars macro action. All variables will be cleared from memory when you close the database.

The TempVar Usage in Macros.

Let us try a quick example to understand the usage in macro:

  1. Select Macros from the Create Menu.

  2. Select SetTempVar Action in the first row.

  3. Type myName in the Name argument.

  4. Type the expression Inputbox(“Type your Name”) in the expression argument.

  5. Save the Macro with a name (say macDefineVar).

  6. Right-click on the macro and select Run from the shortcut menu (or Double-click) to execute the Macro.  The Inputbox() Function will run and will prompt for a value to type.

  7. Type your name and click the OK Command Button.

    Your name is stored in the Variable myName. We have used the Function, InputBox() in the expression argument.  You can use constant values, functions, or expressions to assign values to the variable myName.

  8. Open a new form in the design view.

  9. Insert a Text Box in the details section of the Form.

  10. Type the expression =Tempvars!myName in the Control Source property.

  11. Change the form from Design view to Form View.

Your name will be displayed in the text box.  The above example shows how to define a temporary variable and how to reference it in expressions on a Form.  Let us learn how to remove this variable from memory.

  1. Close the Form.

  2. Select Macro from the Create menu to open up a new macro in the design view.

  3. Select RemoveTempvar from the Action list.

  4. Type myName in the Name parameter.

  5. Save the macro with the name macRemoveVar.

  6. Double-Click on the macRemoveVar macro to execute it.

  7. Open the form again to check whether your name still appears on the text box on the form or not.

The text box will be empty, indicating that the variable myName does not exist in memory.  RemoveTempvar action needs a variable name as a parameter.

TempVar Usage in Query.

Let us do something better than this and more useful in real-world solutions.  Let us calculate the Order-wise Percentage on the sum of Orders Quantity.  We have worked on this problem earlier in the blog post: Percentage on Total Query.  What we need here mainly is the sum of Orders' Quantity to calculate individual order percentages.  In the earlier example, we have used a separate Query to calculate the sum of Orders and linked it with a second Query on Order Number to calculate the percentage.

Here we will initialize a Temporary Variable with the sum of Quantity and use the Variable name in the percentage calculation expression.

  1. Import the Order Details table from the Northwind sample database.

  2. Select Query Design from the Create menu; don't select any table or query from the displayed list.

  3. Change the Query in SQL view; copy and paste the following SQL string and save the Query with the name OrderPercentageQ:

    SELECT [Order Details].OrderID, First([Order Details].UnitPrice) AS UnitPrice, Sum([Order Details].Quantity) AS Quantity
    FROM [Order Details]
    GROUP BY [Order Details].OrderID;
    
  4. Open the macro macDefineVar in the design view.

  5. Change the variable name, myName to TotalQuantity (myName variable will remain in memory).

  6. Change the expression InputBox(“Enter your Name”) to DSum(“Quantity”,”[Order Details]”).  Do not add the = symbol at the beginning of the expression.  Save the macro with the change.

  7. Double-click on the macro to run and calculate the total quantity and store the value into the temporary variable TotalQuantity.

    We will modify the OrderPercentageQ with the addition of a new column that calculates the order-wise percentage of total orders.

  8. Open a new Query in SQL View.

  9. Copy and Paste the following SQL String into the SQL editing window of the new Query and save it with the name OrderPercentageQ2:

    SELECT [Order Details].OrderID, First([Order Details].UnitPrice) AS UnitPrice, Sum([Order Details].Quantity) AS Qty, Sum([quantity])/[tempvars]![totalQuantity]*100 AS Percentage
    FROM [Order Details]
    GROUP BY [Order Details].OrderID;
    
  10. Open the Query in Design View and check how we have written the expression in the last column to calculate the percentage using the temporary variable [tempvars]![totalQuantity].

  11. Change the Query View into Datasheet View to display the Order-wise percentage of Total Quantity.

The TempVar Usage in VBA.

We can work with the Temporary Variable (Tempvars Object) in VBA.

With the Add method, we can define a Temporary Variable and assign an initial value to it.

Add() method of TempVars Object:

    Syntax: TempVars.Add "Variable Name","Initial Value"

    Example-1: TempVars.Add "TotalQuantity", DSum("Quantity", "[Order Details]")

    OR

    Example-2: TempVars!TotalQuantity =  DSum("Quantity", "[Order Details]")

You can define a total of 255 temporary variables in this way. 

Remove method of TempVars Object:

The Remove() method erases only one variable and frees the memory occupied by the variable.

    Syntax: TempVars.Remove "Variable Name"

    Example: TempVars.Remove "TotalQuantity"

RemoveAll method of TempVars Object:

The RemoveAll() removes all the temporary variables defined with the Add() method.

    Syntax: TempVars.RemoveAll

    Example: TempVars.RemoveAll

The Count property gives the count of all temporary variables defined in memory:

Example: Debug.Print TempVars.Count returns the count of temporary variables defined in memory

TempVars Item Indexes.

Each temporary variable defined in memory has an index number starting from 0 to the total number of such variables in memory –1.  Each variable can be referenced by the Item index and can be used to read the Name of the variable or its Value or to assign new values to the variable.

Debug.Print TempVars.Item(0).Name prints the name of the variable.

SumofQuantity = TempVars.Item(0).Value

You can also use this reference to modify the existing value in the temporary variable.

TempVars.Item(0).Value = TempVars.Item(0).Value + 1

You should not use a subscript beyond the existing number of temporary variables in memory otherwise an error will occur.  If you have defined 5 variables, then the valid index numbers are 0 to 4.

Earlier Post Link References:

Share:

1 comment:

  1. [...] LEARN MS-ACCESS TIPS AND TRICKS – Macros and Temporary Variables Apr 2, 2011 … Alerts & Animations, 3D text wizard, graph charts, … Animations. MsgBox with Office Assistant ….. a.p.r.pillai Says: Download a sample database with all the running pr. … [...]

    ReplyDelete

Comments subject to moderation before publishing.

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