+ Reply to Thread
Results 1 to 27 of 27

Count of distinct values between two date ranges

  1. #1
    Forum Contributor
    Join Date
    11-30-2012
    Location
    England
    MS-Off Ver
    Excel 2010
    Posts
    112

    Count of distinct values between two date ranges

    Hi,

    I'm really hoping someone can help me as I've been banging my head against the keyboard for the last few hours and it' starting to hurt!

    I've attached the spreadsheet for ease of reference
    In summary if you look at the formula on the tab '2018_Tbl' cell b11 I'm almost there but need to be able to filter between two dates (start and end of each month).

    I need a formula to count all the distinct project codes on the RAWDATA_2018 Tab column F:F but between the dates on the 2018_tbl (months) and only counting if the value in column AA on the RAWDATA_2018 tab is 1 (exclude zero). I introduced this column as couldn't think of a way to exclude the different cancellation status on et rawdata2018 table column b; wanted to add the reasons to the formula.

    Any help would be greatly appreciated.
    Attached Files Attached Files

  2. #2
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,000

    Re: Count of distinct values between two date ranges

    Use this array formula:

    =SUM(--(FREQUENCY(IF(RAWDATA_2018!$AA$2:$AA$60=1,IF(RAWDATA_2018!$W$2:$W$60>='2018_Tbl'!$B$1,IF(RAWDATA_2018!$W$2:$W$60<='2018_Tbl'!$B$2,MATCH(RAWDATA_2018!$F$2:$F$60,RAWDATA_2018!$F$2:$F$60,0)))),ROW(RAWDATA_2018!$F$2:$F$60)-ROW(RAWDATA_2018!$F$2)+1)>0))

    Do not use whole column references in array formulae, unless you really do have 1,000,000 rows of data AND you are young enough to wait for Excel to process them all.



    Array Formulae are a little different from ordinary formulae in that they MUST be confirmed in the FIRST CELL ONLY by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. After that, the array can be dragged down as normal, to cover the desired range.

    You will know the array is active when you see curly brackets { } - or "curly braces" for those of you in the USA, or "flower brackets" for those of you in India - appear around the outside of your formula. If you do not use CTRL+SHIFT+ENTER you will (almost always) get an error message or an incorrect answer. Press F2 on that cell and try again.

    Don't type the curly brackets yourself - it won't work...
    Attached Files Attached Files
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU.

    Temporary addition of accented to illustrate ongoing problem to the TT: L? fh?ile P?draig sona dhaoibh

  3. #3
    Forum Contributor
    Join Date
    11-30-2012
    Location
    England
    MS-Off Ver
    Excel 2010
    Posts
    112

    Re: Count of distinct values between two date ranges

    Glen, you're a star mate. Even though I won't get back the lost miserable four hours yesterday trying to fathom this out you've resurrected my smile again today I used the whole column reference to save me adjusting the formula each day when I import the new projects into the file.

    Cheers

  4. #4
    Forum Contributor
    Join Date
    11-30-2012
    Location
    England
    MS-Off Ver
    Excel 2010
    Posts
    112

    Re: Count of distinct values between two date ranges

    Hi,

    I've tried adding another IF statement but keep getting an error :'-(

    I need to add an IF statement to filter only 'OSPM' records in Column C (Meeting Type)

  5. #5
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,000

    Re: Count of distinct values between two date ranges

    Try this:

    =SUM(--(FREQUENCY(IF(RAWDATA_2018!$AA$2:$AA$60=1,IF(RAWDATA_2018!$W$2:$W$60>='2018_Tbl'!$B$1,IF(RAWDATA_2018!$W$2:$W$60<='2018_Tbl'!$B$2,IF(RAWDATA_2018!$C$2:$C$60="OSPM",MATCH(RAWDATA_2018!$F$2:$F$60,RAWDATA_2018!$F$2:$F$60,0))))),ROW(RAWDATA_2018!$F$2:$F$60)-ROW(RAWDATA_2018!$F$2)+1)>0))

    You're welcome.



    If that takes care of your original question, please select "Thread Tools" from the menu link above and mark this thread as SOLVED.

    It'd also be appreciated if you were to click the Add Reputation button at the foot of any of the posts of all members who helped you reach a solution.
    Attached Files Attached Files

  6. #6
    Forum Contributor
    Join Date
    11-30-2012
    Location
    England
    MS-Off Ver
    Excel 2010
    Posts
    112

    Re: Count of distinct values between two date ranges

    Glenn,

    it works like a dream mate . . . however it's presented me with another problem but the last one if it can be cracked. I need to count either OSPM or MSV in column C, also need to count everything else but these two types. I have tried using an OR but failed miserably.

    IF(RAWDATA_2018!$C$2:$C$60="OSPM",

  7. #7
    Forum Guru samba_ravi's Avatar
    Join Date
    07-26-2011
    Location
    Hyderabad, India
    MS-Off Ver
    Excel 2021
    Posts
    8,914

    Re: Count of distinct values between two date ranges

    Please Login or Register  to view this content.
    Try this array formula
    Last edited by samba_ravi; 02-22-2018 at 08:40 AM.
    Samba

    Say thanks to those who have helped you by clicking Add Reputation star.

  8. #8
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,000

    Re: Count of distinct values between two date ranges

    OR is simple enough:

    =SUM(--(FREQUENCY(IF(RAWDATA_2018!$AA$2:$AA$60=1,IF(RAWDATA_2018!$W$2:$W$60>='2018_Tbl'!$B$1,IF(RAWDATA_2018!$W$2:$W$60<='2018_Tbl'!$B$2,IF(RAWDATA_2018!$C$2:$C$60={"OSPM","MSV"},MATCH(RAWDATA_2018!$F$2:$F$60,RAWDATA_2018!$F$2:$F$60,0))))),ROW(RAWDATA_2018!$F$2:$F$60)-ROW(RAWDATA_2018!$F$2)+1)>0))

    NOT is less straightforward and is best achieved by including an OR list of excluded terms:

    =SUM(--(FREQUENCY(IF(RAWDATA_2018!$AA$2:$AA$60=1,IF(RAWDATA_2018!$W$2:$W$60>='2018_Tbl'!$B$1,IF(RAWDATA_2018!$W$2:$W$60<='2018_Tbl'!$B$2,IF(RAWDATA_2018!$C$2:$C$60={"TPSM","Yadda Yadda","Blah Blah"},MATCH(RAWDATA_2018!$F$2:$F$60,RAWDATA_2018!$F$2:$F$60,0))))),ROW(RAWDATA_2018!$F$2:$F$60)-ROW(RAWDATA_2018!$F$2)+1)>0))
    Attached Files Attached Files

  9. #9
    Forum Contributor
    Join Date
    11-30-2012
    Location
    England
    MS-Off Ver
    Excel 2010
    Posts
    112

    Re: Count of distinct values between two date ranges

    Glen,

    It's spot-on mate, works a treat . . . . know just need to dissect to understand how it works ;-)

    Best Regards

  10. #10
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,000

    Re: Count of distinct values between two date ranges

    You're welcome.



    If that takes care of your original question, please select "Thread Tools" from the menu link above and mark this thread as SOLVED.

    It'd also be appreciated if you were to click the Add Reputation button at the foot of any of the posts of all members who helped you reach a solution.

  11. #11
    Forum Contributor
    Join Date
    11-30-2012
    Location
    England
    MS-Off Ver
    Excel 2010
    Posts
    112

    Re: Count of distinct values between two date ranges

    just tried this formula to do some count ifs

    =SUM(COUNTIFS(RAWDATA_2018!$B:$B,{"","Resource"},RAWDATA_2018!$W:$W,">="&Lookup_Tbl!$B$11,RAWDATA_2018!$W:$W,"<="&Lookup_Tbl!$C$11)) - This works ok and gives the count expected

    =SUM(COUNTIFS(RAWDATA_2018!$C:$C,{"OPSM","MSV"},RAWDATA_2018!$B:$B,{"","Resource"},RAWDATA_2018!$W:$W,">="&Lookup_Tbl!$B$11,RAWDATA_2018!$W:$W,"<="&Lookup_Tbl!$C$11)) added RAWDATA_2018!$C:$C,{"OPSM","MSV"} and it's returned the incorrect count. It should count everything between two dates that are either OPSM or MSV in one column and blank or resource in another column

  12. #12
    Forum Contributor
    Join Date
    11-30-2012
    Location
    England
    MS-Off Ver
    Excel 2010
    Posts
    112

    Re: Count of distinct values between two date ranges

    Hi Glenn,

    just tried this formula to do some count ifs

    =SUM(COUNTIFS(RAWDATA_2018!$B:$B,{"","Resource"},RAWDATA_2018!$W:$W,">="&Lookup_Tbl!$B$11,RAWDATA_2018!$W:$W,"<="&Lookup_Tbl!$C$11)) - This works ok and gives the count expected

    =SUM(COUNTIFS(RAWDATA_2018!$C:$C,{"OPSM","MSV"},RAWDATA_2018!$B:$B,{"","Resource"},RAWDATA_2018!$W:$W,">="&Lookup_Tbl!$B$11,RAWDATA_2018!$W:$W,"<="&Lookup_Tbl!$C$11)) added RAWDATA_2018!$C:$C,{"OPSM","MSV"} and it's returned the incorrect count. It should count everything between two dates that are either OPSM or MSV in one column and blank or resource in another column

  13. #13
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,000

    Re: Count of distinct values between two date ranges

    Hi. When you add a second array constant, the bit inside the {} to a formula, you are moving from a one-dimensional array (either A or B) to a two dimensional array (either A/X or A/Y or B/X or B/Y). The , separator tells Excel that it's a horizontal array. Unless you tell Excel that the second array is vertical array, the second term is ignored. So..... you were SOOOOO very close.

    =SUM(COUNTIFS(RAWDATA_2018!$C:$C,{"OPSM","MSV"},RAWDATA_2018!$B:$B,{"";"Resource"},RAWDATA_2018!$W:$W,">="&Lookup_Tbl!$B$11,RAWDATA_2018!$W:$W,"<="&Lookup_Tbl!$C$11))

  14. #14
    Forum Contributor
    Join Date
    11-30-2012
    Location
    England
    MS-Off Ver
    Excel 2010
    Posts
    112

    Re: Count of distinct values between two date ranges

    No cigar though! Thanks again

  15. #15
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,000

    Re: Count of distinct values between two date ranges

    I forgot to add.... It's OSPM, not OPSM. You spelled it incorrectly in your formula and I forgot to change it in my post above...

  16. #16
    Forum Contributor
    Join Date
    11-30-2012
    Location
    England
    MS-Off Ver
    Excel 2010
    Posts
    112

    Re: Count of distinct values between two date ranges

    Superb. You've even identified a typo in the data set.

    I've tried this but keep returning zero?

    =SUM(COUNTIFS(RAWDATA_2018!$B:$B,{"OPSM","MSV"},RAWDATA_2018!$B:$B,{"";"Resource"},RAWDATA_2018!$W:$W,">="&$B$1,RAWDATA_2018!$W:$W,"<="&$B$2))

  17. #17
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,000

    Re: Count of distinct values between two date ranges

    If I were you.... I'd take to the drink!!

    1. OPSM is still spelled incorrectly in your formula... and 2) the OSPMs and MSVs are in column C, not in column B

    =SUM(COUNTIFS(RAWDATA_2018!$B:$B,{"OPSM","M

  18. #18
    Forum Contributor
    Join Date
    11-30-2012
    Location
    England
    MS-Off Ver
    Excel 2010
    Posts
    112

    Re: Count of distinct values between two date ranges

    Darn! I think that's great advise mate. It's defo time to log-off and call it a day. Again, a sincere thank-you for digging me out of a few holes today. Enjoy your evening.

    Best Regards

  19. #19
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,000

    Re: Count of distinct values between two date ranges

    No problem. I learned something out of this exchange, too. My challenge is to try to remember it....

  20. #20
    Forum Contributor
    Join Date
    11-30-2012
    Location
    England
    MS-Off Ver
    Excel 2010
    Posts
    112

    Re: Count of distinct values between two date ranges

    I've never really needed to use formulas before so a very steep learning curve mate but very impressed with what's been achieved . . . remembering it tomorrow is indeed the challenge!

  21. #21
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,000

    Re: Count of distinct values between two date ranges

    Hats off to you sir.... You have jumped in at the deep end and have survived!! Not the simplest of formulae to start with

  22. #22
    Forum Contributor
    Join Date
    11-30-2012
    Location
    England
    MS-Off Ver
    Excel 2010
    Posts
    112

    Re: Count of distinct values between two date ranges

    Hi Glen,

    I'm back at it again. I'm trying to add another IF condition "North London & Home Counties" but Excel banner advises that I've 'added too few arguments for this function'


    =SUM(--(FREQUENCY(IF(RAWDATA_2018!$AA$2:$AA$211=1,IF(RAWDATA_2018!$W$2:$W$211>='2018_Tbl'!B89,IF(RAWDATA_2018!$W$2:$W$211<='2018_Tbl'!B90,IF(RAWDATA_2018!$C$2:$C$211="TPSM",IF(RAWDATA_2018!$AB:$AB="North London & Home Counties",MATCH(RAWDATA_2018!$F$2:$F$211,RAWDATA_2018!$F$2:$F$211,0))))),ROW(RAWDATA_2018!$F$2:$F$211)-ROW(RAWDATA_2018!$F$2)+1)>0))

  23. #23
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,000

    Re: Count of distinct values between two date ranges

    A bit unintelligible without a sample sheet!!

  24. #24
    Forum Contributor
    Join Date
    11-30-2012
    Location
    England
    MS-Off Ver
    Excel 2010
    Posts
    112

    Re: Count of distinct values between two date ranges

    It's ok mate. I cracked it ;0) Your wise counsel has not been wasted . .

    =SUM(--(FREQUENCY(IF(RAWDATA_2018!$AA$2:$AA$211=1,IF(RAWDATA_2018!$W$2:$W$211>='2018_Tbl'!$B89,IF(RAWDATA_2018!$W$2:$W$211<='2018_Tbl'!$B90,IF(RAWDATA_2018!$AB$2:$AB$211="North London & Home Counties",IF(RAWDATA_2018!$C$2:$C$211={"OPSM","MSV","IM"},MATCH(RAWDATA_2018!$F$2:$F$211,RAWDATA_2018!$F$2:$F$161,0)))))),ROW(RAWDATA_2018!$F$2:$F$211)-ROW(RAWDATA_2018!$F$2)+1)>0))

  25. #25
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,000

    Re: Count of distinct values between two date ranges

    Quote Originally Posted by HKPHOOY View Post
    I've never really needed to use formulas before so a very steep learning curve mate but very impressed with what's been achieved . . . remembering it tomorrow is indeed the challenge!
    You remembered!!! Woo hoo!!!

  26. #26
    Forum Contributor
    Join Date
    11-30-2012
    Location
    England
    MS-Off Ver
    Excel 2010
    Posts
    112

    Re: Count of distinct values between two date ranges

    I'm pretty chuffed - all thanks to you sir!

  27. #27
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,000

    Re: Count of distinct values between two date ranges

    Awww shucks, you say the nicest things....

+ 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. [SOLVED] identify distinct date ranges and sum associated product based on unique identifier
    By audreyc in forum Excel Formulas & Functions
    Replies: 13
    Last Post: 12-20-2017, 09:45 PM
  2. How can I count the distinct values
    By rizz0 in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 04-13-2017, 09:33 AM
  3. [SOLVED] Macro to count distinct values for each date
    By jbarbara11 in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 06-03-2016, 07:12 AM
  4. Count of Values (Rows) of Most Recent Consecutive Streak (2+ Distinct Values)
    By ExcelForum88 in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 03-13-2016, 12:26 PM
  5. Count Distinct Values
    By trevordsmith in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 07-02-2014, 09:21 PM
  6. [SOLVED] Count Distinct Values
    By djfatboyfats in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 11-20-2012, 07:39 AM
  7. Count Distinct Values?
    By bill_morgan in forum Excel Formulas & Functions
    Replies: 8
    Last Post: 04-26-2005, 10:06 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