Excel AppNote: "Using Dynamic Dialog Boxes" (XE0449)ID: Q110192
|
======================================================================
Microsoft(R) Product Support Services Application Note (Text File)
XE0449: USING DYNAMIC DIALOG BOXES
======================================================================
Revision Date: 12/93
No Disk Included
The following information applies to Microsoft Excel, versions 3.0,
and 4.0.
-----------------------------------------------------------------------
| INFORMATION PROVIDED IN THIS DOCUMENT AND ANY SOFTWARE THAT MAY |
| ACCOMPANY THIS DOCUMENT (collectively referred to as an Application |
| Note) IS PROVIDED "AS IS" WITHOUT WARRANTY OF ANY KIND, EITHER |
| EXPRESSED OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE IMPLIED |
| WARRANTIES OF MERCHANTABILITY AND/OR FITNESS FOR A PARTICULAR |
| PURPOSE. The user assumes the entire risk as to the accuracy and |
| the use of this Application Note. This Application Note may be |
| copied and distributed subject to the following conditions: 1) All |
| text must be copied without modification and all pages must be |
| included; 2) If software is included, all files on the disk(s) must |
| be copied without modification (the MS-DOS(R) utility diskcopy is |
| appropriate for this purpose); 3) All components of this |
| Application Note must be distributed together; and 4) This |
| Application Note may not be distributed for profit. |
| |
| Copyright (C) 1991-1993 Microsoft Corporation. All Rights Reserved. |
| Microsoft and MS-DOS are registered trademarks and Windows is a |
| trademark of Microsoft Corporation |
| Macintosh is a registered trademark of Apple Computer, Inc. |
|---------------------------------------------------------------------|
D E F G H I J K
-------------------------------------------------------------------------
1 |Item # | Item | x | y | width |height | Text |Init/Result
| | Type | | | | | |
-------------------------------------------------------------------------
2 | 0 325 335 4
3 | 1 5 65 9 INVOICE - Shipping
| Information
4 | 2 5 15 20
5 | 3 5 14 42 Invoice #:
6 | 4 8 97 38 109
7 | 5 5 14 65 Customer
8 | 6 5 14 81 Name:
9 | 7 6 97 70 206
10 | 8 5 12 95
11 | 9 14 9 111 147 55 Shipping Method
12 | 10 11 1
13 | 11 112 U.S. Mail
14 | 12 112 Next Day Air
15 | 13 205 167 111 Overnight Carrier:
16 | 14 206 165 141 141
17 | 15 113 14 174 Address Different FALSE
| from Previous?
18 | 16 205 65 196 New Shipping Address
19 | 17 205 11 209
20 | 18 205 9 229 Street
21 | 19 206 61 227 248
22 | 20 205 22 258 City
23 | 21 206 61 253 93
24 | 22 205 168 258 State
25 | 23 206 216 253 93
26 | 24 205 146 280 Zip Code
27 | 25 208 216 279 93
28 | 26 1 5 307 151 Enter Information
29 | 27 2 165 307 151 Cancel Request
-------------------------------------------------------------------------
Note that column D is not part of the dialog box definition table.
This column is provided in this example to help identify the item
numbers. For example, item numbers 11, 12, and 15 are triggers in
this dialog box. Items 13, 14, and 16 through 25 are unavailable
(or dimmed).
| A
------------------------------------------------------------------
1 | dialog_box_macro
2 | =SET.VALUE(K2:K29,"")
3 | =SET.VALUE(K2,4)
4 | =SET.VALUE(K12,1)
5 | =SET.VALUE(K17,FALSE)
6 | finished=FALSE
7 | =WHILE(finished=FALSE)
8 | =IF(K12=1,SET.VALUE(E15:E16,{205;206}))
9 | =IF(K17=FALSE,SET.VALUE(E18:E27,{205;205;205;206;205;206;
| 205;206;205;208}))
10 | dialog_box=DIALOG.BOX(box)
11 | =IF(dialog_box=FALSE,RETURN())
12 | =IF(dialog_box=12)
13 | =SET.VALUE(E15:E16,{5;6})
14 | =SET.VALUE(K2,14)
15 | =ELSE.IF(dialog_box=15)
16 | =SET.VALUE(E18:E27,{5;5;5;6;5;6;5;6;5;8})
17 | =SET.VALUE(K2,19)
18 | =ELSE.IF(dialog_box=26)
19 | finished=TRUE
20 | =END.IF()
21 | =NEXT()
22 | =RETURN()
| A
-------------------------------------------------------------
22 | =ACTIVATE("dbase.xls")
23 | first_cell=TEXTREF(GET.CELL(1,DBASE.XLS!Datab
| ase),TRUE)
24 | =FORMULA(DDBOX.XLM!K6,OFFSET(first_cell,ROWS(
| !Database),0))
25 | =FORMULA(DDBOX.XLM!K9,OFFSET(first_cell,ROWS(
| !Database),1))
26 | =SELECT(OFFSET(first_cell,0,0,ROWS(!Database)
| +1,2))
27 | =SET.DATABASE()
28 | =SELECT(first_cell)
29 | =RETURN()
-----------------------------------------------------------------------
A1: | dialog_box_macro--Names the macro.
-----------------------------------------------------------------------
A2: | =SET.VALUE(K2:K29,"")--Clears the values from the Init\Result
| column.
-----------------------------------------------------------------------
A3: | =SET.VALUE(K2,4)--Sets the default dialog box selection (where
| the insertion point appears in the dialog box) to item 4, the
| Invoice # text box.
-----------------------------------------------------------------------
A4: | =SET.VALUE(K12,1)--Sets the shipping method to 1 (U.S. Mail).
-----------------------------------------------------------------------
A5: | =SET.VALUE(K17,FALSE)--Sets the Address Different from Previous
| check box to FALSE (not selected).
-----------------------------------------------------------------------
A6: | finished=FALSE--Sets the variable <finished> to FALSE. This
| variable is used to determine when the Enter Information
| command button is chosen.
-----------------------------------------------------------------------
A7: | =WHILE(finished=FALSE)--Start of WHILE loop. This loop
| continues until the Enter Information button is chosen
| (finished=TRUE).
-----------------------------------------------------------------------
A8: | =IF(K12=1,SET.VALUE(E15:E16,{205;206}))--If the U.S. Mail
| option button is selected, the Overnight Carrier text box is
| made unavailable (dimmed) by adding 200 to the items in cells
| E15 and E16 in the dialog box definition table.
-----------------------------------------------------------------------
A9: | =IF(K17=FALSE,SET.VALUE(E18:E27,{205;205;205;206;205;206;205;20
| 6;205;208}))--If the Address Different from Previous? check box
| is not selected, the New Address fields (that is, Street, City,
| State, and Zip) are made unavailable.
-----------------------------------------------------------------------
A10: | dialog_box=DIALOG.BOX(box)--Displays the dialog box again with
| the above settings.
-----------------------------------------------------------------------
A11: | =IF(dialog_box=FALSE,RETURN())--Checks to see if the Cancel
| Request command button is chosen and, if it has been (TRUE),
| the macro stops running. (You can also use the BREAK() function
| to break out of the WHILE loop but continue with the rest of
| the macro.
-----------------------------------------------------------------------
A12: | =IF(dialog_box=12), A13: =SET.VALUE(E15:E16,{5;6}), A14:
| =SET.VALUE(K2,14)--If trigger item 12 (that is, the Next Day
| Air option button) is chosen, the Overnight Carrier text and
| text edit box is selected by subtracting 200 from item numbers
| 13 and 14 (in cells E15:E16). The default dialog box selection
| is set to item 14.
-----------------------------------------------------------------------
A15: | =ELSE.IF(dialog_box=15)
-----------------------------------------------------------------------
A16: | =SET.VALUE(E18:E27,{5;5;5;6;5;6;5;6;5;8})
-----------------------------------------------------------------------
A17: | =SET.VALUE(K2,19)--If trigger item 15 (that is, the Address
| Different from Previous? check box) is selected, the text field
| and text boxes for items in cells E18 through E27 are selected
| (enabled) by subtracting 200 from the item number. Also, the
| default dialog box selection is set to item 19.
-----------------------------------------------------------------------
A18: | =ELSE.IF(dialog_box=26) and A19: finished=TRUE--If the Cancel
| Request command button is chosen, the variable <finished> is
| set to TRUE.
-----------------------------------------------------------------------
A20: | =END.IF()--Ends the nested IF statement.
-----------------------------------------------------------------------
A21: | =NEXT()--End of WHILE loop. Go back to the beginning of the
| loop unless <finished> is set to TRUE.
-----------------------------------------------------------------------
A22: | =ACTIVATE("dbase.xls")--Activates the worksheet with the
| database range.
-----------------------------------------------------------------------
A23: | first_cell=TEXTREF(GET.CELL(1,DBASE.XLS!Database),TRUE)--
| GET.CELL() finds the cell reference of the upper-left cell in
| the database range and returns it as text. The TEXTREF()
| function converts this string to a usable reference.
| <First_cell> is a variable set equal to this reference.
-----------------------------------------------------------------------
A24: | =FORMULA(DDBOX.XLM!K6,OFFSET(first_cell,ROWS(!Database),0))--
| Takes the invoice number from K6 in the dialog box definition
| table and places it in the first row below the database. The
| offset function places the information from K6 in the cell
| offset from <First_cell> by the number of rows in the database.
-----------------------------------------------------------------------
A25: | =FORMULA(DDBOX.XLM!K9,OFFSET(first_cell,ROWS(!Database),1))--
| Takes the name from K9 in the dialog definition table and
| places it in the first row below the database. The OFFSET()
| function places the information from K9 in the cell offset from
| <First_cell> by the number of rows in the database and 1 column.
-----------------------------------------------------------------------
A26: | =SELECT(OFFSET(first_cell,0,0,ROWS(!Database)+1,2))--Selects a
| range that is the height plus one row and width of the
| database.
-----------------------------------------------------------------------
A27: | =SET.DATABASE()--Redefines the database range.
-----------------------------------------------------------------------
A28: | =SELECT(first_cell)--Selects the first cell.
-----------------------------------------------------------------------
A29: | =RETURN()--Ends the macro.
-----------------------------------------------------------------------
For this version
of Microsoft Excel See this reference
---------------------------------------------------------------------
Version 4.0 For more information about creating custom
dialog boxes, see pages 263-282 of the "User's
Guide 2."
For more information about creating dynamic
dialog boxes, see pages 280-281 of the "User's
Guide 2."
Version 3.0 for For more information about creating custom
Windows dialog boxes, see pages 624-638 of the "User's
Guide."
For more information about creating dynamic
dialog boxes, see pages 639-641 of the "User's
Guide."
Version 3.0 for For more information about creating custom
the Macintosh dialog boxes, see pages 621-637 of the "User's
Guide."
For more information about creating dynamic
dialog boxes, see pages 635-642 of the "User's
Guide."
--------------------------------------------------------------------
Additional query words: 4.00a
Keywords : kbappnote kbfile kbprg
Version : WINDOWS:3.0,4.0,4.0a; MACINTOSH:3.0,4.0
Platform : MACINTOSH WINDOWS
Issue type : kbinfo
Last Reviewed: May 3, 1999