vba - check if A and B appear n times in a range

CROY1985

Well-known Member
Joined
Sep 21, 2009
Messages
501
Office Version
  1. 365
Platform
  1. Windows
Hi all

I have a vba routine which i use to import some external data and drive some reports.

As part of the process, i need to add some validation to the data that is being imported to check that each of the following appear n times (e.g. 7):
East Scotland
West Scotland
North Scotland
South Scotland
NW England
NE England
Wales
Midlands
East Anglia
SE England
South Cen England
SW England
Greater London

They would appear in column B, and my data range is A3:S107 (the 107 bit should be dynamic, the Column S would be nice to be dynamic but not of great importance)

Basically, if any of them aren't 7, i want to stop the routine. Perhaps giving a msg box with the list and their counts to highlight which area is missing/not complete.

If they are all 7, i'd like to delete all rows where column B contains something other than the list above.


Any help greatly appreciated.
 

Excel Facts

Excel Can Read to You
Customize Quick Access Toolbar. From All Commands, add Speak Cells or Speak Cells on Enter to QAT. Select cells. Press Speak Cells.
I gleaned from the OP that you want to check the unique values of column B for seven occurrences, if the count does not match 7, display a message box with the option to exit the procedure.

Code:
Sub checkBfor7()
Dim sh As Worksheet, lr As Long, c As Range, ans As Variant
Set sh = ActiveSheet
lr = sh.Cells.Find("*", , xlValues, xlPart, xlByRows, xlPrevious).Row
With ActiveSheet
    .Range("B1:B" & lr).AdvancedFilter xlFilterCopy, , .Cells(lr + 2, 1), True
    For Each c In .Cells(lr + 2, 1).CurrentRegion.Offset(1)
        If c <> "" And Application.CountIf(.Range("B1:B" & lr), c.Value) <> 7 Then
            ans = MsgBox(c & " Does not equal 7 occurences.  Do you want to continue?", vbQuestion + vbYesNo, "NOT 7")
            If ans = vbNo Then
                .Cells(lr + 2, 1).CurrentRegion.ClearContents
                Exit Sub
            End If
        End If
    Next
    .Cells(lr + 2, 1).CurrentRegion.ClearContents
End With
End Sub
 
Upvote 0

Forum statistics

Threads
1,215,640
Messages
6,125,976
Members
449,276
Latest member
surendra75

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