Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
Bbeckert
New Member

Value Lookup Based on Slicer

I am semi-new to PowerBI. I've managed to teach myself basic features, but am now out of my depth (I am not a developer). 

 

Objective: Generate a cost estimate per sprint for each software development team under my purview that looks something like this (all dummy data):

Bbeckert_0-1724083224764.png

 

User inputs: A development start date, number of sprints needed to do the work, and team assigned to the work. 

So for the above example, the user would have selected a Development Start Date of 6/3/24, estimated only 2 sprints were needed, and assigned the work to Team 01. 

 

I created an index column that assigns a unique ID to each possible Sprint Start date from which users may choose.

Bbeckert_1-1724083467871.png

 

I then have a calculated column in my Dev Timeline Select table that assigns a Sprint Series number so that I can determine sprint intervals. For example, if the user chooses 6/3 as the Development Start Date, then Start Date for Sprint 1 is 6/3, Sprint 2 is 6/17, etc. But if the user chooses 6/4 as the Development Start Date, then the Start Date for Sprint 1 is 6/4 and Sprint 2 is 6/18. 

Bbeckert_3-1724083728204.png

 

I have another table (Team Cost) that shows the cost of each team over these intervals (again, all dummy data).

Bbeckert_8-1724084619718.png

 

In my head, the workflow is:

User selects Team from Slicer 1; User selects Dev Start Date from Slicer 2 --> Look up Sprint Series associated with Start Date selected --> Filter Team Cost table to only values for sprints in that Sprint Series --> Display cost for selected team over specified number of sprints

 

Where I'm stuck is getting the visual table to only show costs associated with a given sprint series as shown in the top of the message. I can get it to filter to a single team, but the visual table will show the cost associated with all dates, not just the ones in the sprint series selected.

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Thank lbendlin
Hi, @Bbeckert 

Based on your description, I have created these two tables:

Table1:

vjianpengmsft_0-1724396339560.png

Table2:

vjianpengmsft_1-1724396357770.png

Relationship:

vjianpengmsft_2-1724396504369.png

 

First, I created a numeric range parameter:

vjianpengmsft_3-1724396525096.png

vjianpengmsft_4-1724396734155.png

vjianpengmsft_5-1724396752810.png

vjianpengmsft_6-1724396777542.png

I created two more slicers:

vjianpengmsft_7-1724396894847.png

vjianpengmsft_8-1724396920727.png

 

I've created a new measure using the following DAX expression. This measure returns the last date of the user's selected sprint series:

Measure =   
        VAR _spring = SELECTEDVALUE(Spring[Spring])
	VAR _team = SELECTEDVALUE(Table2[Team])
	VAR _date = SELECTEDVALUE(Table1[Dev Start Date])
	VAR _index = CALCULATE(
		SELECTEDVALUE(Table1[Sprint Series]),
		'Table1'[Dev Start Date] = _date
	)
	VAR _next_index = IF(
		_spring = 1,
		_index,
		_index + (_spring - 1) * 10
	)
	RETURN
		MAXX(
			FILTER(
				ALL('Table1'),
				'Table1'[Sprint Index] = _next_index
			),
			'Table1'[Dev Start Date]
		)

I've created another metric to control the display of the corresponding project date:

Measure 2 = 
        VAR _start = SELECTEDVALUE(Table2[Sprint Start])
	VAR _end = SELECTEDVALUE(Table2[Sprint End])
	VAR _spring_1_devdate = IF(
		SELECTEDVALUE(Spring[Spring]) = 1,
		SELECTEDVALUE(Table1[Dev Start Date])
	)
	RETURN
		IF(
			_end = [Measure] || _start = [Measure],
			1,
			0
		)

Create a table visual as follows:

vjianpengmsft_9-1724397726443.png

Here are the results:

When I select a sprint, and I select the corresponding team and dev date:

vjianpengmsft_10-1724397823006.png

vjianpengmsft_11-1724397838893.png

 

vjianpengmsft_12-1724397866503.png

When I choose 2 sprints:

vjianpengmsft_13-1724397929846.png

I've provided the PBIX file used this time below.

 

 

Best Regards

Jianpeng Li

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

 

 

View solution in original post

4 REPLIES 4
Anonymous
Not applicable

Thank lbendlin
Hi, @Bbeckert 

Based on your description, I have created these two tables:

Table1:

vjianpengmsft_0-1724396339560.png

Table2:

vjianpengmsft_1-1724396357770.png

Relationship:

vjianpengmsft_2-1724396504369.png

 

First, I created a numeric range parameter:

vjianpengmsft_3-1724396525096.png

vjianpengmsft_4-1724396734155.png

vjianpengmsft_5-1724396752810.png

vjianpengmsft_6-1724396777542.png

I created two more slicers:

vjianpengmsft_7-1724396894847.png

vjianpengmsft_8-1724396920727.png

 

I've created a new measure using the following DAX expression. This measure returns the last date of the user's selected sprint series:

Measure =   
        VAR _spring = SELECTEDVALUE(Spring[Spring])
	VAR _team = SELECTEDVALUE(Table2[Team])
	VAR _date = SELECTEDVALUE(Table1[Dev Start Date])
	VAR _index = CALCULATE(
		SELECTEDVALUE(Table1[Sprint Series]),
		'Table1'[Dev Start Date] = _date
	)
	VAR _next_index = IF(
		_spring = 1,
		_index,
		_index + (_spring - 1) * 10
	)
	RETURN
		MAXX(
			FILTER(
				ALL('Table1'),
				'Table1'[Sprint Index] = _next_index
			),
			'Table1'[Dev Start Date]
		)

I've created another metric to control the display of the corresponding project date:

Measure 2 = 
        VAR _start = SELECTEDVALUE(Table2[Sprint Start])
	VAR _end = SELECTEDVALUE(Table2[Sprint End])
	VAR _spring_1_devdate = IF(
		SELECTEDVALUE(Spring[Spring]) = 1,
		SELECTEDVALUE(Table1[Dev Start Date])
	)
	RETURN
		IF(
			_end = [Measure] || _start = [Measure],
			1,
			0
		)

Create a table visual as follows:

vjianpengmsft_9-1724397726443.png

Here are the results:

When I select a sprint, and I select the corresponding team and dev date:

vjianpengmsft_10-1724397823006.png

vjianpengmsft_11-1724397838893.png

 

vjianpengmsft_12-1724397866503.png

When I choose 2 sprints:

vjianpengmsft_13-1724397929846.png

I've provided the PBIX file used this time below.

 

 

Best Regards

Jianpeng Li

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

 

 

Bbeckert
New Member

For the purposes of this post, the Team Cost values are just randomly generated numbers. So the Sprint for Team 01 starting on 6/3 should show as $149,944 in both tables I pasted. Sorry for the confusion on that.

Please provide sample data that covers your issue or question completely, in a usable format (not as a screenshot).

Do not include sensitive information or anything not related to the issue or question.

If you are unsure how to upload data please refer to https://community.fabric.microsoft.com/t5/Community-Blog/How-to-provide-sample-data-in-the-Power-BI-...

Please show the expected outcome based on the sample data you provided.

Want faster answers? https://community.fabric.microsoft.com/t5/Desktop/How-to-Get-Your-Question-Answered-Quickly/m-p/1447...

lbendlin
Super User
Super User

how did you get to the 149944?

Helpful resources

Announcements
November Power BI Update Carousel

Power BI Monthly Update - November 2025

Check out the November 2025 Power BI update to learn about new features.

Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.