How to create data validation circles for printing in Excel

For a Microsoft Excel 97 version of this article, see 159493 .

Summary

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


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

More Information

Microsoft provides programming examples 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. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and debug procedures. Microsoft support professionals can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific needs.
If you have limited programming experience, you may want to contact a Microsoft Certified Partner or Microsoft Advisory Services. For more information, visit these Microsoft Web sites:

Microsoft Certified Partners -

https://partner.microsoft.com/global/30000104

Microsoft Advisory Services - http://support.microsoft.com/gp/advisoryservice

For more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site:

http://support.microsoft.com/default.aspx?scid=fh;EN-US;CNTACTMS

Sample Macro

 Sub AddValidationCirclesForPrinting()

Dim DataRange As Range
Dim c As Range
Dim count As Integer
Dim o As Shape

'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()


Dim shp As Shape

'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


To use the sample macro, follow these steps:

  1. Start a new workbook.
  2. Turn on the Visual Basic Editor (press ALT+F11).
  3. On the Insert menu, click Module.
  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.
  6. Save the workbook.NOTE: The workbook must be open for you 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.

  7. Open the workbook you want to evaluate for invalid data, and activate the appropriate worksheet.
  8. On the Tools menu, point to Macro, and then click Macros. Click to 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 receive the message

    There are no cells with data validation on this sheet.
    and the macro will end.
  9. Print the worksheet.
  10. After you print the worksheet, you can run the RemoveValidationCircles macro to remove the circles. On the Tools menu, point to Macro, and then click Macros. Select RemoveValidationCircles in the list of macros, and then click Run.
Svojstva

ID članka: 213773 - posljednja izmjena: 13. srp 2009. - verzija: 1

Povratne informacije