XL97: Macro to Create Data Validation Circles for PrintingLast reviewed: March 13, 1998Article ID: Q159493 |
The information in this article applies to:
SUMMARYIn 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 INFORMATIONMicrosoft 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 Suberrhandler: 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
|
Additional query words: XL97 8.00
© 1998 Microsoft Corporation. All rights reserved. Terms of Use. |