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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Anonymous
Not applicable

Dynamic Formula for Power Query

Hello All

 

I have a column called "Period ID" and need to replace Period ID 65 with 122. I am using this formula which works fine:

 

= Table.ReplaceValue(#"Replaced Value2",each [PeriodId], each if [PeriodId]=65 and [ApplicationId]>=34 and [ApplicationId]<=36 then 122 else [PeriodId],Replacer.ReplaceValue,{"PeriodId"})

 

The problem I have is this report pulls from an SQL database once a week bringing in new data. Therfore the Period ID changes each week. This week it is 65 and next week it will be 66, the week after 67. The same goes for the replacement value, this week it is 122, next week it will be 123 and so on. Is there a way I can set the formula so that it dynamically changes each time the Period ID Changes. This week replace 65 with 122, next week replace 66 with 123, etc.? I have to keep the ApplicationIDs in the formulas as show above since they target which lines needs changed. Thanks for any help!

1 ACCEPTED SOLUTION
AlB
Super User
Super User

Hi @Anonymous 

If this week, week number 41 is the one you take as base, then:

 

= Table.ReplaceValue(#"Replaced Value2",each [PeriodId], each if [PeriodId]=65+Date.WeekOfYear(DateTime.LocalNow())-41 and [ApplicationId]>=34 and [ApplicationId]<=36 then 122+Date.WeekOfYear(DateTime.LocalNow())-41 else [PeriodId],Replacer.ReplaceValue,{"PeriodId"})

Please mark the question solved when done and consider giving kudos if posts are helpful.

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

Cheers 

 

SU18_powerbi_badge

View solution in original post

5 REPLIES 5
rogletree
Helper III
Helper III

I'm just spitballing here but you could do something like depending on what the week of the year is, you could set the replace value and the replaced-with value relative to that.

For example, if the current week of the year is 30 and you need to replace all period id's of 50 with 65, then do something like: if the period id = (Date.WeekOfYear([date]) + 20) replace it with (Date.WeekOfYear([date]) + 35). Then the next week, the week of year would increase by 1, therefor increasing the period id and replacement value also by 1. Just incorporate that into the function you already have.

 

Edit: looks like the other person said the same thing as me but a few minutes sooner and with the actual formula haha.

AlB
Super User
Super User

Hi @Anonymous 

If this week, week number 41 is the one you take as base, then:

 

= Table.ReplaceValue(#"Replaced Value2",each [PeriodId], each if [PeriodId]=65+Date.WeekOfYear(DateTime.LocalNow())-41 and [ApplicationId]>=34 and [ApplicationId]<=36 then 122+Date.WeekOfYear(DateTime.LocalNow())-41 else [PeriodId],Replacer.ReplaceValue,{"PeriodId"})

Please mark the question solved when done and consider giving kudos if posts are helpful.

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

Cheers 

 

SU18_powerbi_badge

Anonymous
Not applicable

Worked perfect auto-updating this week. Thanks AIB!

Anonymous
Not applicable

Thanks AIB. I just plugged it in and so far looks beautiful. The real test will be the data refresh next week.

 

Being that I plugged it in using this week as the base, am I correct in assuming that next week the formula will find the next week's value ( which increases by 1) and replace it accordingly?

@Anonymous 

Correct

 

Please mark the question solved when done and consider giving kudos if posts are helpful.

 

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

 

Cheers 

 

SU18_powerbi_badge

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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

Top Solution Authors
Top Kudoed Authors