Recently, we discussed about the case of unwieldy data and how we lookup what we want using formulas like SUMIFS. Today, let us learn few more ways to solve the same problem.
First, a re-cap of the problem:
Here is a data-set:

The problem – build a lookup formula
And the problem. Oh, simple. Write a lookup formula to find how many customer walk-ins we have on any given day.
In the previous article, we discussed how to use SUMIFS to solve this problem. There were several amazing & awesome solutions shared by our readers in the comments section too.
Suitable structure spawns simple solutions
Poorly structured is the 2nd biggest problem of analysts. The first one is not enough coffee. That is why there is a dictum in the data analytics world.
Structure is everything
So, we can easily solve our lookup problem, if our data were to magically re-arranged in 2 column fashion – Data & Value.

This transformation can be done in 2 ways:
Option #1: Transforming Data – Using Formulas
We can use data fetching formulas like OFFSET or INDEX to re-arrange data in 2 columns.
Assuming,
- Our 2D data is in a named range data,
- There are running numbers starting with 0 in the cell J5
We can use below formula to fetch first column:
=IFERROR(INDEX(data,2*(INT(J5/7))+1,MOD(J5,7)+1),"")
for the second column, below formula works:
=IFERROR(INDEX(data,2*(INT(J5/7)+1),MOD(J5,7)+1),"")
How does this formula work?
I will explain the formula for first column. Deciphering 2nd column formula is your homework.
Here is the formula again: =IFERROR(INDEX(data,2*(INT(J5/7))+1,MOD(J5,7)+1),"")
Before understanding the formula, let’s take a minute to examine the structure of our raw data.
- Odd rows contain dates
- Even rows contain values
- There are 7 columns in total
- So to get the first date, we need to go to row 1 (first odd number), column 1
- To get the first value, we need to go to row 2 (first even number), column 1
- But to get 8th date, we need to go to row 3(2nd odd number), column 1
- So on
Let’s go from inside out.
2*(INT(J5/7))+1portion: This gives row number (ie odd number). J5 refers to running number and its value is 0. So we get 2*(INT(0/7))+1 = 1- This will be 3 when J5 becomes J12 (ie 8th date)
MOD(J5,7)+1portion: This gives column number. It will result in values 1 thru 7 in a cyclical fashion. Thanks to MOD.INDEX(data, ..., ...)portion: Now that we have both row & column numbers, INDEX formula kicks in and gets the corresponding date.IFERROR(INDEX(...),"")portion: This is to help in case we ran out of all dates & values in our INDEX formula. Read about IFERROR here.
Once you have the formulas for first date & value, simply drag them to get rest of the values.
Option #2: Transforming data – Using VBA
VBA Macros are perfect for scenarios like this. Usually transformation is something you need to do every-time you import data from external systems. So simply write a macro that can do this automatically.
Assuming our data is in the range data and the first cell of our extraction range is startHere, you can use below macro:
Sub rearrangeData()
'takes the values in DATA named range and rearranges them
'from the named cell startHere
Dim cell As Range, i As Long, j As Long, evenRow As Boolean, firstRow As Long
i = 0
j = 0
firstRow = Range("data").Cells(1).Row
For Each cell In Range("data")
evenRow = (cell.Row - firstRow + 1) Mod 2 = 0
If evenRow Then
Range("startHere").Offset(j, 1).Value = cell.Value
j = j + 1
Else
Range("startHere").Offset(i, 0).Value = cell.Value
i = i + 1
End If
Next cell
End Sub
How does this macro work?
Before jumping in to the lines of code and demystifying the logic, Let’s understand what we need to do:
- For each cell of data,
- If it is in odd row, put the cell data in Date column at end
- Else, put the cell data in Value column at end
- Repeat
This is what our code is trying to do.
Let’s examine the For Each loop, as this is the most critical part of our macro.
- For each cell in the range data
- We check if we are in evenRow using simple arithmetic on row numbers
- If we are in evenRow then
- We put the cell value in row j (number of values so far), column 2
- We increment j
- Else
- We put the cell value in row i (number of dates so far), column 1
- We increment i
- Close the IF condition
- We check for next cell in the data range
Advantages of Transformation over SUMIFS approach
Both options for transforming data have few advantages:
- They work with any type of data (unlike SUMIFS, which works only for numeric lookups and has few other issues)
- Once data is restructured, you can do other types of analysis like creating pivot tables, adding extra calculated columns etc. easily.
Download Example Workbook
Click here to download example workbook that shows original SUMIFS solution, both options for transforming data & few other formulas. Play with it to learn more. Check out the code by pressing ALT+F11.
How would you transform data?
My favorite techniques for transforming data are – VBA, formulas, Power Query, pivot tables & SQL. Depending on the situation, time availability, where my data is, I choose one of these options to scrub my data.
What about you? How do you clean up / scrub data like this? Please share you thoughts & tips with us in comments.
Instructions for washing your dirty data
If your work involves scrubbing dirty data, check out below tutorials too:
- Extract numbers from text using VBA and formulas
- Filling blank cells with above values in tables
- Cleaning up in-correctly formatted dates
- Fixing in-correctly formatted phone numbers
- Reverse a list using INDEX formula
- Transpose a table using formulas

















6 Responses to “Make VBA String Comparisons Case In-sensitive [Quick Tip]”
Another way to test if Target.Value equal a string constant without regard to letter casing is to use the StrCmp function...
If StrComp("yes", Target.Value, vbTextCompare) = 0 Then
' Do something
End If
That's a cool way to compare. i just converted my values to strings and used the above code to compare. worked nicely
Thanks!
In case that option just needs to be used for a single comparison, you could use
If InStr(1, "yes", Target.Value, vbTextCompare) Then
'do something
End If
as well.
Nice tip, thanks! I never even thought to think there might be an easier way.
Regarding Chronology of VB in general, the Option Compare pragma appears at the very beginning of VB, way before classes and objects arrive (with VB6 - around 2000).
Today StrComp() and InStr() function offers a more local way to compare, fully object, thus more consistent with object programming (even if VB is still interpreted).
My only question here is : "what if you want to binary compare locally with re-entering functions or concurrency (with events) ?". This will lead to a real nightmare and probably a big nasty mess to debug.
By the way, congrats for you Millions/month visits 🙂
This is nice article.
I used these examples to help my understanding. Even Instr is similar to Find but it can be case sensitive and also case insensitive.
Hope the examples below help.
Public Sub CaseSensitive2()
If InStr(1, "Look in this string", "look", vbBinaryCompare) = 0 Then
MsgBox "woops, no match"
Else
MsgBox "at least one match"
End If
End Sub
Public Sub CaseSensitive()
If InStr("Look in this string", "look") = 0 Then
MsgBox "woops, no match"
Else
MsgBox "at least one match"
End If
End Sub
Public Sub NotCaseSensitive()
'doing alot of case insensitive searching and whatnot, you can put Option Compare Text
If InStr(1, "Look in this string", "look", vbTextCompare) = 0 Then
MsgBox "woops, no match"
Else
MsgBox "at least one match"
End If
End Sub