Formula Forensics No. 005 – Zebras and Checker-Boards

Share

Facebook
Twitter
LinkedIn

This week in Formula Forensics we’ll look at, Zebra Stripes and Checker-board Conditional Formatting.

This idea is inspired by a number of posts over the past few years asking about zebra stripes but specifically BobR who in in June 2011, also asked about Checkerboards in the post: Want to be an excel conditional-formatting Rock Star, Comment No. 154.

I got the conditional format for alternating row and column colors,

Is there a conditional format to make it a checkerboard whereas the cell A2 will remove either the conditional for the row or column and then alternately to A4, B1, B3 etc?


Chandoo responded fairly quickly with this Conditional Formatting formula:

=IF(MOD(ROW(),2)=1,MOD((ROW()-1)*8+COLUMN(),2)=0,MOD((ROW()-1)*8+COLUMN(),2)=1)

Unbeknownst to Chandoo I posted this about a minute later:

=ISODD(ROW()+COLUMN())

Both formula correctly answer BobR’s question.

So today we’re going to pull apart Zebra Stripes and Checker Boards and see what makes them tick.

As always you can follow along in a download file here: Download File.

 

ZEBRA STRIPES

Zebra Stripes as Conditional Formatting is simply applied using a simple formula within Conditional Formatting.

=MOD(ROW(),2)=0

Conditional Formatting requires a formula that returns a boolean “True” to apply a format or a Boolean “False” to not Apply a format.

So the formula is better read as: If MOD(ROW(),2)=0

And  If MOD(ROW(),2)=0, the formula will evaluate as True

This is best evaluated as 3 columns on a worksheet.

In cells

B5:B10 The formula =Row() returns the Row Number

C5:C10 The formula =Mod(Row() ,2) returns the Mod of Row Number, divided by 2

The Mod function returns the remainder of the division of the Row Number divided by 2,

So in Row 5, Mod(Row(),2) = Mod(5, 2) = 5/2 = 2 Remainder 1 = 1

and in Row 6, Mod(Row(),2) = Mod(6, 2) = 6/2 = 3 Remainder 0 = 0

D5:D10 The formula =Mod(Row() ,2)=0 checks the remainder against the value 0

This is what evaluates to either True or False depending on the Row number.

Where the Values are True the Format will be applied (Even Rows)

The Conditional Formatting can be applied to Odd Rows If the Formula is slightly altered

=Mod(Row() ,2)=1

 

Similarly the formatting can be applied to Columns using

=MOD(COLUMN(),2)=0/1

 

 

CHECKER BOARDS

RobR received two responses to his Checker-Board Conditional Formatting request.

=IF(MOD(ROW(),2)=1,MOD((ROW()-1)*8+COLUMN(),2)=0,MOD((ROW()-1)*8+COLUMN(),2)=1)

and

=ISODD(ROW()+COLUMN())

Lest see what’s inside these two formula.

 

=IF(MOD(ROW(),2)=1,MOD((ROW()-1)*8+COLUMN(),2) =0, MOD( (ROW() -1)*8+COLUMN(),2)=1)

This is a simple If Formula with 3 components

=IF(MOD(ROW(),2)=1,MOD((ROW()-1)*8+COLUMN(),2)=0,MOD((ROW()-1)*8+COLUMN(),2)=1)

If Condition        MOD(ROW(),2)=1

Value if True:     MOD((ROW()-1)*8+COLUMN(),2)=0

Value if False:    MOD((ROW()-1)*8+COLUMN(),2)=1

The If Condition is already known to us, as it’s the same formula used in the Zebra Stripes above.

It evaluates to True when it is on an Odd Row.

So when it is an Odd numbered Row Excel will look at MOD((ROW()-1)*8+COLUMN(),2)=0

And when it is an Even numbered Row Excel will look at MOD((ROW()-1)*8+COLUMN(),2)=1

We can notice that these are the same formulas which have a different ending of =0 and =1

MOD((ROW()-1)*8+COLUMN(),2)=0

This section Takes each Row subtracts 1 and then multiplies this number by 8. This can be expressed as simply as saying multiply the Row * 8.

This will always return an Even Number and could have been simplified to Row()*2

MOD((ROW()-1)*8+COLUMN(),2)=0

The next bit adds the column number to the previous Even Number.

So now this part will be Odd when the column is Odd and Even when the column is Even.

MOD((ROW()-1)*8+COLUMN(),2)=0

The remainder of the formula is the same as the Zebra Stripes formula.

An Odd Number (Odd Columns) in the section above will return a 1 as the result of =Mod(Odd,2)

An Even Number (Even Columns) in the section above will return a 0 as the result of =Mod(Odd,2)

When evaluated against 0 will return True for Even Columns and False for Odd Columns.

Now the exact same happens in the False section of the If formula except that it is evaluated against 1.

 

=ISODD(ROW()+COLUMN())

I tackled this problem from a different direction to Chandoo.

Knowing that Even + Even = Even and Even + Odd = Odd and that the row and Column Numbers increase in each direction by 1 each Row/Column, it was simply a matter of adding the Row and Column numbers together and checking if it was Odd or Even

The Excel function IsOdd() and IsEven() both return a Boolean “True” if the contents are Odd or “Even” respectively. This negates an external truth check as described above.

This is easily shown by adding a formula to the Checker area

=Row()+Column()

Excel 2003: The above formula won’t work in Excel 2003.

Try this instead =Mod(Row()+Column(),2)=1


If the alternate shading is required a switch to

=ISEVEN(ROW()+COLUMN())

Does the trick.

Excel 2003: The above formula won’t work in Excel 2003.

Try this instead =Mod(Row()+Column(),2)=0


Learn More About Conditional Formatting Here:

http://chandoo.org/wp/2009/03/13/excel-conditional-formatting-basics/

and

http://chandoo.org/wp/2008/03/13/want-to-be-an-excel-conditional-formatting-rock-star-read-this/

and

http://chandoo.org/wp/2008/10/14/more-than-3-conditional-formats-in-excel/

 

DOWNLOAD

You can download a copy of the above file and follow along, Download Here.

 

OTHER POSTS IN THIS SERIES

You can learn more about how to pull Excel Formulas apart in the following posts

Formula Forensics 001 – Tarun’s Problem

Formula Forensics 002 – Joyce’s Question

Formula Forensics 003 – Lukes Reward

Formula Forensics 004 – Freds Problem

 

We Need Your Help !

If you have a neat formula that you would like to share and explain, try putting pen to paper and draft up a Post as Luke did in Formula Forensics 003. or this post.

If you have a formula that you don’t understand and would like explained but don’t want to write a post also send it in to Chandoo or Hui.

 

 

 

Facebook
Twitter
LinkedIn

Share this tip with your colleagues

Excel and Power BI tips - Chandoo.org Newsletter

Get FREE Excel + Power BI Tips

Simple, fun and useful emails, once per week.

Learn & be awesome.

Welcome to Chandoo.org

Thank you so much for visiting. My aim is to make you awesome in Excel & Power BI. I do this by sharing videos, tips, examples and downloads on this website. There are more than 1,000 pages with all things Excel, Power BI, Dashboards & VBA here. Go ahead and spend few minutes to be AWESOME.

Read my storyFREE Excel tips book

Overall I learned a lot and I thought you did a great job of explaining how to do things. This will definitely elevate my reporting in the future.
Rebekah S
Reporting Analyst
Excel formula list - 100+ examples and howto guide for you

From simple to complex, there is a formula for every occasion. Check out the list now.

Calendars, invoices, trackers and much more. All free, fun and fantastic.

Advanced Pivot Table tricks

Power Query, Data model, DAX, Filters, Slicers, Conditional formats and beautiful charts. It's all here.

Still on fence about Power BI? In this getting started guide, learn what is Power BI, how to get it and how to create your first report from scratch.

11 Responses to “Who is the most consistent seller? [BYOD]”

  1. Hui... says:

    The Date column in the sample file is Text not Dates

  2. Great Chandoo. Keep it up, Looking forward more from BYOD..

  3. gayani says:

    Thanks

  4. Frank Tonsen says:

    With Excel 2013 the pivot table could be connected to the data model which provides a distinct count.

  5. Mak says:

    This will do for invoice count
    =COUNTIF(F:F,H12)
    Instead of
    =COUNTIFS(sales[SELLER],$H12)

  6. Alejandro says:

    Excellent document. How did you make the last graphic? Witch app. Thanks for answer.

  7. Chris says:

    Can someone tell me what =countif(sales[date],sales[date]) is counting? The value is 19. Its found in the =SUMPRODUCT(IF(sales[SELLER]=H12,1/COUNTIFS(sales[SELLER],H12,sales[date],sales[date]),0))

    • Vândalo says:

      Hi Chris,

      =countif(sales [date],sales[date]) function is counting the unique dates in the table.

      Vândalo

  8. Nguyen says:

    Excellent document!

    Can you explain more about the calculation on Weighted consistency? More specific the small number is 0,00001 ?

    How come the number should be smaller if there is more sellers?

  9. TS says:

    Hi,

    Not understood this formula: {=SUMPRODUCT(IF(sales[SELLER]=H12,1/COUNTIFS(sales[SELLER],H12,sales[date],sales[date]),0))}

    Please explain.

    Thanks.

Leave a Reply