+ Reply to Thread
Results 1 to 11 of 11

Count cell values under column with today's date header

  1. #1
    Registered User
    Join Date
    08-23-2013
    Location
    USA
    MS-Off Ver
    Excel 2010
    Posts
    18

    Count cell values under column with today's date header

    Hey all, I'm trying to count up the number of occurrances of a specific cell value, but only under the the column with today's date for a header.

    I have a range from S7:BC16 with data. In range S3:BC3 I have dates, one of which will be today's date. I want to find which column is today's date, then count up the number of times "A" appears. I could write VBA for this, but as the range is going to be moving upon inserting/deleting rows, I'd much rather prefer to use a formula.

    Currently I have
    Formula: copy to clipboard
    Please Login or Register  to view this content.
    then just add up that again with columns T, U, V, W,.....etc. I know there is a better way to go about this, I'm just not seeing it.... any help would be greatly appreciated. Thanks!

  2. #2
    Forum Expert daffodil11's Avatar
    Join Date
    07-11-2013
    Location
    Phoenixville, PA
    MS-Off Ver
    MS Office 2016
    Posts
    4,465

    Re: Count cell values under column with today's date header

    I'd probably use INDIRECT to create a dynamic range.

    Are you trying to get a sum of all columns with that date, or one column at a time?

  3. #3
    Registered User
    Join Date
    08-23-2013
    Location
    USA
    MS-Off Ver
    Excel 2010
    Posts
    18

    Re: Count cell values under column with today's date header

    The headers will be like 8/1/2013, 8/2/2013..... through the 6th or 7th of the next month. So it should only ever count up the instances of one column.

    Can't say I've ever used the INDIRECT function before and I've got something off here..

    Formula: copy to clipboard
    Please Login or Register  to view this content.


    Giving me a ref error, so something is definitely wrong in there. Any ideas on what I'm messing up?

  4. #4
    Forum Expert daffodil11's Avatar
    Join Date
    07-11-2013
    Location
    Phoenixville, PA
    MS-Off Ver
    MS Office 2016
    Posts
    4,465

    Re: Count cell values under column with today's date header

    Ahh, you need to use some Char() in there.

    INDIRECT() translates a string into actual reference, whereas =A1 is standard format, =INDIRECT(CHAR(ROW(A1)+64)&99-98) also =A1. Your reference is just missing the CHAR() part which translates a number into a letter so you get a Column reference. The alphabet begins at char(64), so you just use char(64+?) to get there.

  5. #5
    Forum Expert daffodil11's Avatar
    Join Date
    07-11-2013
    Location
    Phoenixville, PA
    MS-Off Ver
    MS Office 2016
    Posts
    4,465

    Re: Count cell values under column with today's date header

    =COUNTIF(RANGE,CRITERIA) where CRITERIA = "A" and RANGE = rows 7 to 16 and columns S to BC.

    =COLUMN(R1) = 82

    Now we know the parameters, we just build around them.

    =COUNTIF(RANGE,"A")

    =COUNTIF(R7:R16,"A")

    =COUNTIF(INDIRECT(CHAR(82+MATCH(TODAY(),$S$3:$BC$3,0))&7&":"&CHAR(82+MATCH(TODAY(),$S$3:$BC$3,0))&16),"A")

    which translates into R7:R16, adjusted X Columns where X = the header that matches today in S3:BC3
    Last edited by daffodil11; 09-23-2013 at 01:48 PM.

  6. #6
    Forum Expert daffodil11's Avatar
    Join Date
    07-11-2013
    Location
    Phoenixville, PA
    MS-Off Ver
    MS Office 2016
    Posts
    4,465

    Re: Count cell values under column with today's date header

    As for figuring how to get AA:BC efficiently, I'm a little stuck.
    Maybe MOD to pull remainder with a denominator of 26 to overflow to the next letter of the alphabet.


    Where's a guru when you need one?

  7. #7
    Forum Guru Jonmo1's Avatar
    Join Date
    03-08-2013
    Location
    Bryan, TX
    MS-Off Ver
    Excel 2010
    Posts
    9,763

    Re: Count cell values under column with today's date header

    Try

    =COUNTIF(INDEX(S7:BC16,0,MATCH(TODAY(),S3:BC3,0)),"A")


    And I would consider re-evaluating your process and avoid inserting/deleting rows.
    Perhaps try clearcontents and then pasting in new data.

  8. #8
    Forum Expert daffodil11's Avatar
    Join Date
    07-11-2013
    Location
    Phoenixville, PA
    MS-Off Ver
    MS Office 2016
    Posts
    4,465

    Re: Count cell values under column with today's date header

    Thanks Jonmo!

  9. #9
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Count cell values under column with today's date header

    I would use OFFSET for this.

    =COUNTIF(OFFSET($R$7:$R$13, , MATCH(TODAY(), $S$3:$BC$3, 0), ,), "a")


    Love JonMo's use of INDEX.
    _________________
    Microsoft MVP 2010 - Excel
    Visit: Jerry Beaucaire's Excel Files & Macros

    If you've been given good help, use the icon below to give reputation feedback, it is appreciated.
    Always put your code between code tags. [CODE] your code here [/CODE]

    ?None of us is as good as all of us? - Ray Kroc
    ?Actually, I *am* a rocket scientist.? - JB (little ones count!)

  10. #10
    Registered User
    Join Date
    08-23-2013
    Location
    USA
    MS-Off Ver
    Excel 2010
    Posts
    18

    Re: Count cell values under column with today's date header

    Thank you all! Exactly what I was trying to do. Just couldn't get a way working to use match as the column finder, and count up in that column. Thinking using index is the way I need to go. Thanks Jonmo, and thanks everyone else too!

  11. #11
    Forum Guru Jonmo1's Avatar
    Join Date
    03-08-2013
    Location
    Bryan, TX
    MS-Off Ver
    Excel 2010
    Posts
    9,763

    Re: Count cell values under column with today's date header

    You're welcome.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. Count Row values based on Column header
    By sramakrishna in forum Excel Formulas & Functions
    Replies: 9
    Last Post: 06-06-2013, 09:07 AM
  2. Macro Count Days Between Today's Date and Column D
    By Gard5096 in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 12-11-2012, 10:00 PM
  3. Count if values based on column header
    By vijanand1279 in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 11-02-2012, 03:17 PM
  4. Count Unique Text & blanks in one column prior to Today's date
    By VBSK8R in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 11-21-2011, 01:25 PM
  5. count the number of cells within a column with a date <= today's d
    By Cachod1 in forum Excel - New Users/Basics
    Replies: 2
    Last Post: 01-27-2006, 07:30 PM

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1