Dax to get Previus 7 days from selected value

mahmed1

Well-known Member
Joined
Mar 28, 2009
Messages
2,302
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
Hey Guys, how can i replicate this in powerbi Dax like excel below

Say i had a table like this

DateScore
29/11/2022​
50​
30/11/2022​
20​
01/12/2022​
7​
02/12/2022​
22​
03/12/2022​
15​
04/12/2022​
26​
05/12/2022​
27​
06/12/2022​
27​
07/12/2022​
13​
08/12/2022​
31​
09/12/2022​
32​
10/12/2022​
22​
11/12/2022​
19​
12/12/2022​
45​
13/12/2022​
24​
14/12/2022​
30​
15/12/2022​
42​
16/12/2022​
34​
17/12/2022​
33​
18/12/2022​
33​
19/12/2022​
21​
20/12/2022​
37​
21/12/2022​
10​
22/12/2022​
34


What i wanted to do is based on whatever date i select - i want to pull back the value from what it was 7 days ago - eg say i selected 20/12/2022
the data table results should look like this
SELECTED DATE20/12/2022
20/12/202237
13/12/202224
06/12/202227
29/11/202250
 

Excel Facts

Control Word Wrap
Press Alt+Enter to move to a new row in a cell. Lets you control where the words wrap.
PLEASE use XL2BB.
Book1
ABCDE
1DateScoreSelected Date12/20/2022
211/29/202215DateScore
311/30/2022812/20/202235
412/01/20221112/19/202210
512/02/20224712/18/202232
612/03/20224312/17/202210
712/04/2022812/16/202221
812/05/20221312/15/202218
912/06/20222512/14/202222
1012/07/202229
1112/08/202210
1212/09/202225
1312/10/202217
1412/11/202219
1512/12/202249
1612/13/202222
1712/14/202222
1812/15/202218
1912/16/202221
2012/17/202210
2112/18/202232
2212/19/202210
2312/20/202235
2412/21/202242
2512/22/202216
Sheet1
Cell Formulas
RangeFormula
D1D1=PROPER("SELECTED DATE")
A2:A25A2=SEQUENCE(24,,DATEVALUE("11/29/2022"))
D3:D9D3=SEQUENCE(7,,DATE(YEAR(E1), MONTH(E1), DAY(E1)),-1)
E3:E9E3=XLOOKUP(D3#,A2#,B2:B25)
Dynamic array formulas.

The Score column was generated using RANDARRAY and then using Copy/Paste Values, not what you posted.
I showed the last 7 day's values based on the Start Date selected. It was unclear what your goal is. You said "i want to pull back the value from what it was 7 days ago", but then show 12/20/2022 as your "SELECTED DATE" and a list of dates and their values from the table, and some of those dates are more than 7 days earlier than 12/20/2022.
 
Upvote 0
The data I used is this (slightly different to yours a copying from PDF was a nuisance): (Note that dates are in UK format - dd/mm/yyyy)

Book1
GH
1DateScore
222/12/20227
321/12/202222
420/12/202215
519/12/202226
618/12/202227
717/12/202227
816/12/202213
915/12/202231
1014/12/202232
1113/12/202222
1212/12/202219
1311/12/202245
1410/12/202224
1509/12/202230
1608/12/202242
1707/12/202234
1806/12/202233
1905/12/202233
2004/12/202221
2103/12/202237
2202/12/202210
2301/12/202234
2430/11/202250
2529/11/202219
Table2


I then added a 'Presets' table into which I typed the date I was interested in:

Book1
C
1date
220-Dec-22
Table2


Which produced this output:

Book1
KL
1DateScore
220/12/202215
313/12/202222
406/12/202233
529/11/202219
Table2


The Powerquery code to do this is here: To understand it I suggest you create a blank query, copy the code into it and then follow it step by step. Remember that the small table is named 'tblPresets' and the data table is 'Table5'.

Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table5"]}[Content],
    #"Changed Type1" = Table.TransformColumnTypes(Source,{{"Date", Int64.Type}}),
    Presets = Excel.CurrentWorkbook(){[Name="tblPresets"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Presets,{{"date", type date}}),
    #"Appended Query" = Table.Combine({#"Changed Type", #"Changed Type1"}),
    #"Changed Type2" = Table.TransformColumnTypes(#"Appended Query",{{"date", Int64.Type}}),
    #"Filled Down" = Table.FillDown(#"Changed Type2",{"date"}),
    #"Added Custom" = Table.AddColumn(#"Filled Down", "Custom", each Number.Mod([Date]-[date],7)),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Custom.1", each [Date]-[date]<=0),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom1", each ([Custom.1] = true) and ([Custom] = 0)),
    #"Changed Type3" = Table.TransformColumnTypes(#"Filtered Rows",{{"Date", type date}, {"date", type date}}),
    #"Removed Other Columns" = Table.SelectColumns(#"Changed Type3",{"Date", "Score"})
in
    #"Removed Other Columns"

HTH
 
Upvote 0

Forum statistics

Threads
1,223,099
Messages
6,170,107
Members
452,302
Latest member
TaMere

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