Create a Dynamically Generated List Based on Criteria

PacSum

New Member
Joined
Jan 8, 2017
Messages
30
I've exhausted the googlez and yet to find exactly what I'm looking for.

I have two worksheets. Sheet two is a drop in report from another source. Sheet one aims to provide a simple way for a user to query data on sheet two. Below is a watered down example of what I'm looking for. This table represents how many miles each person ran on a specific day:


TonySallyMarthaBilly
Monday5131
Tuesday241
Wednesday221
Thursday1
Friday721
Saturday31
Sunday212

<tbody>
</tbody>

On sheet 1, I want to have 2 drop downs that in conjunction will populate a result in a third cell:

NAME (static dropdown list)DAY (dynamic dropdown list)RESULT

<tbody>
</tbody>

Name will contain all 4 names at all times. Simple enough. Here's the caveat. I want the DAY drop down to be dynamically populated ONLY with days > 0.

Ex 1. Select Tony in cell A1, cell B1 contains Monday, Tuesday, Saturday. Select Monday in cell B1 and cell C1 populates with 5.
Ex 2. Select Billy in cell A1, cell B1 contains all 7 days. Select Tuesday in cell B1 and cell C1 populates with with 1.

I know I could manually create 4 lists relative to each person's name. But imagine this example amplified x100.

How would one go about creating a list from this format in this manner?
 
Last edited:
Howdy,

Maybe I did not understand the problem requirement ... but ...

Create dynamic range for names (automatic extension to the addition of another name), and range for weekdays.
In sheet 1 where you want to get the result you use a formula like:
= Index (range with data, match (cell with name in dropdown, .....), match (cell with weekdays in dropdown, ......))

The range for names is simple.

The issue is populating the list for weekdays. I don't want all 7 days. I ONLY want days which could bring up a non zero amount.
 
Upvote 0

Excel Facts

When they said...
When they said you are going to "Excel at life", they meant you "will be doing Excel your whole life".
Not sure what the problem is, try this Example file, see if it helps!!
https://app.box.com/s/5y49zjtrvmh92ooma6nf4mx7dru7xwqw

Yep. Works perfect. I actually created it from scratch and it worked as well. When i tried to apply to my application, it failed.

The problem is, in my infinite wisdom, I assumed with the basic knowledge I have of excel and VBA that I'd be able to transcribe what you sent to actually fit my true data set, which isn't the same, but pretty closely mirrors it. As you can see, I failed miserably.

To be more precise, this is exactly how the data is laid out:

TimBobJoeSueGusCam
Parameter 1050013
Parameter 2054022
Parameter 3034031
Parameter 4400041
Parameter 5110010
Parameter 6261010

<tbody>
</tbody>


In a post preview I realize that the visual doesn't properly represent cells.

Names start on cell D7.
Parameters (days in previous example) related to names start on cell A10
Data begins in cell D10

And I may not have articulated appropriately before, but no cell will be blank. All non-data is represented by a 0. 0 should omit the parameter from showing in the drop down, not a blank.

@MickG, thanks again for the help. Even if you don't end up seeing this message, I very much appreciate you getting me started. I'll be sure to pay it forward once I begin to learn all of this a little bit more.

On that note, do you have any advice on courses/tutorials/how-to's etc on working with advanced excel projects like this?
 
Last edited:
Upvote 0
To expand a bit on pgc01's comment, you can do all this without VBA. In L1 (or some range of your choice) put the formula below and drag down as necessary. Then set up a Name in the Name Manager called List2, with the formula:

=OFFSET(Sheet1!$L$1,0,0,SUM(--(Sheet1!$L$1:$L$10<>"")))

Now select B1, go to Data Validation, select List, and enter

=List2

as the source. Finally, enter the C1 formula in. You should end up with something like this:

ABCDEFGHIJKLM
1JoeParameter 34Parameter 2
2Parameter 3
3Parameter 6
4
5
6
7TimBobJoeSueGusCam
8
9
10Parameter 1050013
11Parameter 2054022
12Parameter 3034031
13Parameter 4400041
14Parameter 5110010
15Parameter 6261010

<tbody>
</tbody>
Sheet1

Worksheet Formulas
CellFormula
C1=INDEX($D$10:$I$15,MATCH($B$1,$A$10:$A$15,0),MATCH($A$1,$D$7:$I$7,0))

<tbody>
</tbody>

<tbody>
</tbody>

Array Formulas
CellFormula
L1{=IFERROR(INDEX($A$10:$A$15,SMALL(IF(INDEX($D$10:$I$15,0,MATCH($A$1,$D$7:$I$7,0))<>0,ROW($A$10:$A$15)-ROW($A$10)+1),ROWS($L$1:$L1))),"")}

<tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>
 
Last edited:
Upvote 0
The range for names is simple.

The issue is populating the list for weekdays. I don't want all 7 days. I ONLY want days which could bring up a non zero amount.

You have already received an answer from Erik W, to have just those days / parameters that are not zero.
 
Upvote 0
You have already received an answer from Erik W, to have just those days / parameters that are not zero.

This is true. But this was not the case when you wrote your message or when I responded to you.

@Eric W
This worked perfectly. Thank you.
 
Last edited:
Upvote 0
This is true. But this was not the case when you wrote your message or when I responded to you.


You are right. I have assumed that the part with days> 0 is something easy for you and I only proposed the data extraction solution.
Next time I will read more carefully and I will not make any assumptions ...
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,979
Messages
6,122,559
Members
449,089
Latest member
Motoracer88

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top