XL97: Macro to Create Data Validation Circles for Printing

Last reviewed: March 13, 1998
Article ID: Q159493
The information in this article applies to:
  • Microsoft Excel 97 for Windows

SUMMARY

In Microsoft Excel 97, you can use the Circle Invalid Data button on the Auditing toolbar to identify cells that contain values that are outside the data validation limits that you've set. A red circle is placed around each identified cell. These circles are not printed when you print the worksheet. This is by design in Microsoft Excel.

This article provides a macro that you can use to display circles around invalid data for printing purposes.

MORE INFORMATION

Microsoft provides examples of Visual Basic for Applications procedures for illustration only, without warranty either expressed or implied, including, but not limited to the implied warranties of merchantability and/or fitness for a particular purpose. The Visual Basic procedures in this article are provided 'as is' and Microsoft does not guarantee that they can be used in all situations. While Microsoft support engineers can help explain the functionality of a particular macro, they will not modify these examples to provide added functionality, nor will they help you construct macros to meet your specific needs. If you have limited programming experience, you may want to consult one of the Microsoft Solution Providers. Solution Providers offer a wide range of fee-based services, including creating custom macros. For more information about Microsoft Solution Providers, call Microsoft Customer Information Service at (800) 426-9400.

Sample Macro

Sub AddValidationCirclesForPrinting()

    'Set an object variable to all of the cells on the active
    'sheet that have data validation -- if an error occurs, run
    'the error handler and end the procedure
    On Error GoTo errhandler
    Set DataRange = Cells.SpecialCells(xlCellTypeAllValidation)
    On Error GoTo 0

    count = 0

    'Loop through each cell that has data validation
    For Each c In DataRange

       'If the validation value for the cell is false, then draw
       'a circle around the cell. Set the circle's fill to
       'invisible, the line color to red and the line weight to
       '1.25
       If Not c.Validation.Value Then
           Set o = ActiveSheet.Shapes.AddShape(msoShapeOval, _
               c.Left - 2, c.Top - 2, c.Width + 4, c.Height + 4)
           o.Fill.Visible = msoFalse
           o.Line.ForeColor.SchemeColor = 10
           o.Line.Weight = 1.25

           'Change the name of the shape to InvalidData_ + count
           count = count + 1
           o.Name = "InvalidData_" & count
       End If
   Next
   Exit Sub

errhandler:
   MsgBox "There are no cells with data validation on this sheet."

End Sub

Sub RemoveValidationCircles()

    'Remove each shape on the active sheet that has a name starting
    'with InvalidData_

    For Each shp In ActiveSheet.Shapes
       If shp.Name Like "InvalidData_*" Then shp.Delete
    Next

End Sub


How to Use the Sample Macro

  1. Start a new workbook.

  2. Press ALT+F11 to activate the Visual Basic Editor.

  3. Click Module on the Insert menu.

  4. Type the sample macro in the code window of the module sheet.

  5. On the File menu, click "Close and Return to Microsoft Excel" (or press ALT+Q).

  6. Save the workbook.

NOTE: The workbook must be open to use the macros. If you would like the macros to be available each time you start Microsoft Excel, save the workbook in the \Program Files\Microsoft Office\Office\XlStart folder.

  1. Open the workbook you wish to evaluate for invalid data and activate the appropriate worksheet.

  2. On the Tools menu, point to Macro, and then click Macros. Select "AddValidationCirclesForPrinting" in the list of macros and click Run.

    Each cell that contains invalid data is now surrounded by a red circle (up to a maximum of 255 cells per worksheet). If the active worksheet does not contain any cells with data validation, you will instead receive the message

    There are no cells with data validation on this sheet.

    and the macro will end.

  3. Print the worksheet.

  4. After you print the worksheet, you can run the RemoveValidationCircles macro to remove the circles. On the Tools menu, point to Macro and click Macros. Select RemoveValidationCircles in the list of macros and click Run.


Additional query words: XL97 8.00
Keywords : kbcode kbprg kbualink97 xlvbainfo xlprint
Version : WINDOWS:97
Platform : WINDOWS
Issue type : kbhowto


THE INFORMATION PROVIDED IN THE MICROSOFT KNOWLEDGE BASE IS PROVIDED "AS IS" WITHOUT WARRANTY OF ANY KIND. MICROSOFT DISCLAIMS ALL WARRANTIES, EITHER EXPRESS OR IMPLIED, INCLUDING THE WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. IN NO EVENT SHALL MICROSOFT CORPORATION OR ITS SUPPLIERS BE LIABLE FOR ANY DAMAGES WHATSOEVER INCLUDING DIRECT, INDIRECT, INCIDENTAL, CONSEQUENTIAL, LOSS OF BUSINESS PROFITS OR SPECIAL DAMAGES, EVEN IF MICROSOFT CORPORATION OR ITS SUPPLIERS HAVE BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGES. SOME STATES DO NOT ALLOW THE EXCLUSION OR LIMITATION OF LIABILITY FOR CONSEQUENTIAL OR INCIDENTAL DAMAGES SO THE FOREGOING LIMITATION MAY NOT APPLY.

Last reviewed: March 13, 1998
© 1998 Microsoft Corporation. All rights reserved. Terms of Use.