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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Syndicate_Admin
Administrator
Administrator

Fill column with last value, only if condition is met.

Hello everyone, I hope someone can arientar me on the following:

I have a dataset that looks like this,

WeekSales_Store1Sales_Store2Sales_Store3
1912 4
20 3411
21
22
221041

As you can tell in almost every week there is at least one empty field; This does not affect analysis at all.

However, in week 21 and 22 the three columns are empty, this is where I have the problem. I would like the rows that meet the condition of having the three empty columns, to be filled with the values of the previous week. This 3 new final columns.

The expected result is as follows:

WeekSales_Store1Sales_Store2Sales_Store3Sales_Store1Sales_Store2Sales_Store3
1912 412 4
20 3411 3411
21 3411
22 3411
2210411041

Another acceptable outcome is as follows:

WeekSales_Store1Sales_Store2Sales_Store3
1912 4
20 3411
21 3411
22 3411
221041

I hope someone can guide me on the solution to follow. Best regards.

1 ACCEPTED SOLUTION
v-jingzhang
Community Support
Community Support

Hi @Anonymous 

 

You can add these calculated columns to your table. The last three columns are similar. You just need to modify the sales store column it references. 

Flag = IF(ISBLANK('Table (2)'[Sales_Store1]) && ISBLANK('Table (2)'[Sales_Store2]) && ISBLANK('Table (2)'[Sales_Store3]), 0, 1)
NewSales_Store1 = IF('Table (2)'[Flag] = 1, 'Table (2)'[Sales_Store1], 
var _previousWeek = MAXX(FILTER('Table (2)','Table (2)'[Week] < EARLIER('Table (2)'[Week]) && 'Table (2)'[Flag] = 1),'Table (2)'[Week])
var _previousSales = MAXX(FILTER('Table (2)','Table (2)'[Week] = _previousWeek), 'Table (2)'[Sales_Store1])
return _previousSales)
NewSales_Store2 = IF('Table (2)'[Flag] = 1, 'Table (2)'[Sales_Store2], 
var _previousWeek = MAXX(FILTER('Table (2)','Table (2)'[Week] < EARLIER('Table (2)'[Week]) && 'Table (2)'[Flag] = 1),'Table (2)'[Week])
var _previousSales = MAXX(FILTER('Table (2)','Table (2)'[Week] = _previousWeek), 'Table (2)'[Sales_Store2])
return _previousSales)
NewSales_Store3 = IF('Table (2)'[Flag] = 1, 'Table (2)'[Sales_Store3], 
var _previousWeek = MAXX(FILTER('Table (2)','Table (2)'[Week] < EARLIER('Table (2)'[Week]) && 'Table (2)'[Flag] = 1),'Table (2)'[Week])
var _previousSales = MAXX(FILTER('Table (2)','Table (2)'[Week] = _previousWeek), 'Table (2)'[Sales_Store3])
return _previousSales)

vjingzhang_0-1669777951868.png

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

View solution in original post

2 REPLIES 2
v-jingzhang
Community Support
Community Support

Hi @Anonymous 

 

You can add these calculated columns to your table. The last three columns are similar. You just need to modify the sales store column it references. 

Flag = IF(ISBLANK('Table (2)'[Sales_Store1]) && ISBLANK('Table (2)'[Sales_Store2]) && ISBLANK('Table (2)'[Sales_Store3]), 0, 1)
NewSales_Store1 = IF('Table (2)'[Flag] = 1, 'Table (2)'[Sales_Store1], 
var _previousWeek = MAXX(FILTER('Table (2)','Table (2)'[Week] < EARLIER('Table (2)'[Week]) && 'Table (2)'[Flag] = 1),'Table (2)'[Week])
var _previousSales = MAXX(FILTER('Table (2)','Table (2)'[Week] = _previousWeek), 'Table (2)'[Sales_Store1])
return _previousSales)
NewSales_Store2 = IF('Table (2)'[Flag] = 1, 'Table (2)'[Sales_Store2], 
var _previousWeek = MAXX(FILTER('Table (2)','Table (2)'[Week] < EARLIER('Table (2)'[Week]) && 'Table (2)'[Flag] = 1),'Table (2)'[Week])
var _previousSales = MAXX(FILTER('Table (2)','Table (2)'[Week] = _previousWeek), 'Table (2)'[Sales_Store2])
return _previousSales)
NewSales_Store3 = IF('Table (2)'[Flag] = 1, 'Table (2)'[Sales_Store3], 
var _previousWeek = MAXX(FILTER('Table (2)','Table (2)'[Week] < EARLIER('Table (2)'[Week]) && 'Table (2)'[Flag] = 1),'Table (2)'[Week])
var _previousSales = MAXX(FILTER('Table (2)','Table (2)'[Week] = _previousWeek), 'Table (2)'[Sales_Store3])
return _previousSales)

vjingzhang_0-1669777951868.png

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

Thank you very much, that's what I was looking for. It helped me a lot. Best regards.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.