"Type Mismatch" error with specialcells(xlConstants) variable

Ark68

Well-known Member
Joined
Mar 23, 2004
Messages
4,570
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
I have this code that assess a range of cells and formats individual cells within that range based on values preceeding and proceeding that cell.

Rich (BB code):
                         With ws_cs.Range("H" & dr_trow & ":Q" & dr_trow) 'Rows(dr_trow)
                            On Error Resume Next
                            Set c = .SpecialCells(xlConstants)                    'cells with content (not empty, not formulas)
                            If c Is Nothing Then MsgBox "no cells", vbCritical: Exit Sub
                            On Error GoTo 0
                            If c <> "AUTO" Then
                                For Each cl In c.Cells                                'loop through this cells
                                    If cl.Column = 1 Then bLeft = False Else bLeft = (cl.Offset(, -1).Interior.ColorIndex = xlNone And Len(cl.Offset(, -1).Value) = 0)     'the cell at the LHS is empty and no color
                                    If cl.Column = ActiveSheet.Columns.Count Then bRight = False Else bRight = (cl.Offset(, 1).Interior.ColorIndex = xlNone And Len(cl.Offset(, 1).Value) = 0)
                                    If Not bLeft And Not bRight Then cl.ClearContents
                                Next
                            End If
                        End With

Someone here at Mr Excel was kind enough to provide this code for me, so I'm not extirely certain I know how it works, especially how the variable 'c' works.
When I reach the line I get a "Type mismatch" error when it encounters a cell that has the value "AUTO" in it.
This code is supposed to reformat all cells in that range when the criteria is met except if the cell has a value of "AUTO". Those cells will not be reformatted.

Is anyone able to share how to resolve the error and do what I set out to do with this code? For what I can gather, 'c' must be a range maybe ... something that can't be compared.
 

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.
See if this does what you are after:
Note: c is not a single cell but a range of selected cells, so c <> "AUTO" does not work.
The For loop uses cl to represent each individual cell in the range c. It at this point that you can test whether the cell (cl) = "AUTO"

VBA Code:
                         With ws_cs.Range("H" & dr_trow & ":Q" & dr_trow) 'Rows(dr_trow)
                            On Error Resume Next
                            Set c = .SpecialCells(xlConstants)                    'cells with content (not empty, not formulas)
                            If c Is Nothing Then MsgBox "no cells", vbCritical: Exit Sub
                            On Error GoTo 0
                                For Each cl In c.Cells                                'loop through this cells
                                    If cl.Value <> "AUTO" Then
                                        If cl.Column = 1 Then bLeft = False Else bLeft = (cl.Offset(, -1).Interior.ColorIndex = xlNone And Len(cl.Offset(, -1).Value) = 0)     'the cell at the LHS is empty and no color
                                        If cl.Column = ActiveSheet.Columns.Count Then bRight = False Else bRight = (cl.Offset(, 1).Interior.ColorIndex = xlNone And Len(cl.Offset(, 1).Value) = 0)
                                        If Not bLeft And Not bRight Then cl.ClearContents
                                    End If
                                Next
                        End With
 
Upvote 0
Solution
Thank you so much Alex. That worked wonderfully!
Enjoy your day.
 
Upvote 0

Forum statistics

Threads
1,223,909
Messages
6,175,315
Members
452,634
Latest member
cpostell

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top