+ Reply to Thread
Results 1 to 15 of 15

Formula for an output of repeat occurrences in a given range of data?

  1. #1
    Registered User
    Join Date
    03-10-2018
    Location
    TEXAS
    MS-Off Ver
    2010 Excel
    Posts
    9

    Formula for an output of repeat occurrences in a given range of data?

    I work at a high school and we are in the process of scheduling. I have a spreadsheet that includes the course requests for about 70 of our students who will be most difficult to schedule. Each students' row includes seven to eight columns, each course request in a column.

    I would like to do the following:

    For a given course code (example- Algebra 1), I want to know how many students have requested both that course and any other course. How many students have a request for Algebra 1 and English 1? How many students have a request for Algebra 1 and Keyboarding? How many students have a request for Algebra 1 and Biology? After I'm done w/Algebra 1, I'd need to do the same for every course.

    I know this is complex and might require multiple steps, just wondering if it is possible in excel.

    I am unable to post a link to a google spreadsheet with the document I'm using since I just joined, but can provide upon request.

  2. #2
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,830

    Re: Formula for an output of repeat occurrences in a given range of data?

    You can attach the workbook here - no need for a link.

    1. Make sure that your sample data are REPRESENTATIVE of your real data. The use of unrepresentative data is very frustrating and can lead to long delays in reaching a solution.

    2. Make sure that your desired results are also shown (mock up the results manually).

    3. Make sure that all confidential data is removed or replaced with dummy data first (e.g. names, addresses, E-mails, etc.).

    4. Try to avoid using merged cells as they cause lots of problems.

    Unfortunately the attachment icon doesn't work at the moment, so to attach an Excel file you have to do the following: just before posting, scroll down to Go Advanced and then scroll down to Manage Attachments. Now follow the instructions at the top of that screen.

    Please pay particular attention to point 2 (above): without an idea of your intended outcomes, it is often very difficult to offer appropriate advice.
    Ali


    Enthusiastic self-taught user of MS Excel who's always learning!
    Don't forget to say "thank you" in your thread to anyone who has offered you help.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    Forum Rules (updated August 2023): please read them here.

  3. #3
    Registered User
    Join Date
    03-10-2018
    Location
    TEXAS
    MS-Off Ver
    2010 Excel
    Posts
    9

    Re: Formula for an output of repeat occurrences in a given range of data?

    Please see attached.

    1. Data in the document is the actual data.
    2. Second tab contains desired output format, although I just need the output (not concerned with format)
    3. There is no confidential data.
    4. There should be no merged cells.

    I have followed the instructions via Manage Attachments.
    Attached Files Attached Files

  4. #4
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,830

    Re: Formula for an output of repeat occurrences in a given range of data?

    The attached workbook may help you, or at least get you started. I've created a matrix for you (section shown below). I use a grid like this when working out timetable option blocks from choices at school. Someone here gave me help with this some time ago - I think it was originally designed for a golf tournament. Hope it helps.

    Excel 2016 (Windows) 32 bit
    B
    C
    D
    E
    F
    G
    H
    I
    J
    K
    L
    M
    2
    A12477
    A12478
    A12528
    A12532
    A12539
    A12541
    A12542
    A12546
    A12547
    A12550
    A12561
    3
    A12477
    1
    0
    0
    1
    0
    0
    0
    0
    1
    0
    0
    4
    A12478
    0
    1
    1
    0
    0
    1
    0
    0
    0
    0
    0
    5
    A12528
    0
    1
    30
    0
    3
    9
    0
    0
    0
    18
    2
    6
    A12532
    1
    0
    0
    31
    0
    0
    1
    3
    28
    2
    0
    7
    A12539
    0
    0
    3
    0
    3
    0
    0
    0
    0
    0
    0
    8
    A12541
    0
    1
    9
    0
    0
    9
    0
    0
    0
    0
    0
    9
    A12542
    0
    0
    0
    1
    0
    0
    1
    1
    0
    0
    0
    10
    A12546
    0
    0
    0
    3
    0
    0
    1
    3
    0
    0
    0
    11
    A12547
    1
    0
    0
    28
    0
    0
    0
    0
    28
    2
    0
    12
    A12550
    0
    0
    18
    2
    0
    0
    0
    0
    2
    20
    2
    13
    A12561
    0
    0
    2
    0
    0
    0
    0
    0
    0
    2
    2
    Sheet: Single list of courses

    It uses this formula:

    =SUMPRODUCT((MMULT(('Conflict Matrix 2018.csv'!$A$3:$H$63=C$2)+('Conflict Matrix 2018.csv'!$A$3:$H$63=$B3),{1;1;1;1;1;1;1;1})=2)+0)

    I've formatted the cells so that zeros do not show.
    Attached Files Attached Files

  5. #5
    Registered User
    Join Date
    03-10-2018
    Location
    TEXAS
    MS-Off Ver
    2010 Excel
    Posts
    9

    Re: Formula for an output of repeat occurrences in a given range of data?

    This is amazing and perfect (and now overwhelming!).


    A million thanks!This will be a great help.

  6. #6
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,830

    Re: Formula for an output of repeat occurrences in a given range of data?

    You're welcome! Shout if you need any further help.

    I thought it was pretty amazing, too, when it was first offered to me as a solution about a year ago.

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

  7. #7
    Registered User
    Join Date
    03-10-2018
    Location
    TEXAS
    MS-Off Ver
    2010 Excel
    Posts
    9

    Re: Formula for an output of repeat occurrences in a given range of data?

    Some students changed their requests and some requests need to be added, adding additional columns beyond H. I tried just making the adjustment to the formula but I've messed it up. Do you mind taking a look, or can I walk you through what I've done and you tell me how to proceed?

    Thanks!

  8. #8
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,830

    Re: Formula for an output of repeat occurrences in a given range of data?

    It would be best to attach the workbook here. It will be easier to troubleshoot that way.

  9. #9
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,830

    Re: Formula for an output of repeat occurrences in a given range of data?

    Still waiting to see the new, muddled workbook.

  10. #10
    Registered User
    Join Date
    03-10-2018
    Location
    TEXAS
    MS-Off Ver
    2010 Excel
    Posts
    9

    Re: Formula for an output of repeat occurrences in a given range of data?

    Please see attached. The Blue tabs are the tabs that you used previously. The green tab has the new requests/cleaned up so that everything in columns A-L should be included. Many thanks for taking a look!
    Attached Files Attached Files

  11. #11
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,830

    Re: Formula for an output of repeat occurrences in a given range of data?

    My formula will choke on entries like this, I am afraid:

    A12572 Alternates:V13077
    It isn't 'clever' enough to deal with alternatives. These will need to be separated out into their own columns.

    However, here's how it works:

    1. Make sure that you have a list of all possible (available) courses down the left and across the top of the clash matrix (these need to be in the same order top to bottom and left to right).
    2. Make sure that the arrays in the formula in C3 are long/wide enough to cover the entire range of choices on the choices sheet (red sections below).
    3. Make sure that the number of 1s in the matrix in the formula equal the number of columns in the lookup array (i.e. if there are 10 columns of choices, there must be 10 1s - green section below).
    4. Once this is all checked, copy the formula across and down.

    =SUMPRODUCT((MMULT(('Conflict Matrix 2018.csv'!$A$3:$H$63=C$2)+('Conflict Matrix 2018.csv'!$A$3:$H$63=$B3),{1;1;1;1;1;1;1;1})=2)+0)
    Last edited by AliGW; 04-03-2018 at 12:57 PM.

  12. #12
    Registered User
    Join Date
    03-10-2018
    Location
    TEXAS
    MS-Off Ver
    2010 Excel
    Posts
    9

    Re: Formula for an output of repeat occurrences in a given range of data?

    So if I'm going to just used the green tab where the "alternates" have been removed, do I need to save that as a .csv and replace the 'Conflict Matrix 2018.csv' in the formula with 'Requests by student.csv'?

    Can you tell me what the =2 and +0 mean in the formula, though I should not touch them, correct?

  13. #13
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,830

    Re: Formula for an output of repeat occurrences in a given range of data?

    This is what you will need, once you have checked that the lists across the top and down the side are correct:

    =IFERROR(SUMPRODUCT((MMULT(('Requests by Student'!$A$1:$L$59=C$2)+('Requests by Student'!$A$1:$L$59=$B3),{1;1;1;1;1;1;1;1;1;1;1;1})=2)+0),"")

    =2 checks where both criteria are met (i.e. the arrays generated by the formula added together make 2), which indicates one match

    +0 just forces the calculation to be numbers

    No, please do NOT change either!

    I recommend you use the evaluate formula feature to step through the formula to see what it's doing.

  14. #14
    Registered User
    Join Date
    03-10-2018
    Location
    TEXAS
    MS-Off Ver
    2010 Excel
    Posts
    9

    Re: Formula for an output of repeat occurrences in a given range of data?

    The SUMPRODUCT formula you gave me worked perfectly! I'm not sure what the difference between that and the IFERROR formula are, but thanks so much! I can definitely repeat this on my own from now on.

  15. #15
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,830

    Re: Formula for an output of repeat occurrences in a given range of data?

    All the IFERROR bit does is return a blank if the formula returns an error. It is still the same SUMPRODUCT MMULT formula!

    Glad you understand it well enough now to adapt yourself.

+ 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. Replies: 1
    Last Post: 02-14-2017, 10:29 PM
  2. VBA Code to grab data give critiria in textbox and output data range to cell range. Help!?
    By exclusiveicon in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 06-26-2014, 05:31 PM
  3. [SOLVED] Formula for counting the number of occurrences within a range of cells AND Strings help
    By V1gilante in forum Excel Formulas & Functions
    Replies: 9
    Last Post: 01-14-2014, 07:58 PM
  4. Replies: 9
    Last Post: 04-29-2013, 09:45 AM
  5. Formula to Count the Number of Occurrences of a Text String in a Range
    By poug1903 in forum Excel Programming / VBA / Macros
    Replies: 7
    Last Post: 11-10-2011, 06:49 AM
  6. Excel 2007 : Count Occurrences of Text in Data Range
    By gtlandis in forum Excel General
    Replies: 5
    Last Post: 09-22-2011, 11:42 PM
  7. Replies: 1
    Last Post: 09-18-2009, 04:15 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