Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
I have data in the following form:
Date | Balance |
1-May-19 | 120 |
2-May-19 | 121 |
3-May-19 | 122 |
4-May-19 | 123 |
5-May-19 | 124 |
6-May-19 | 125 |
7-May-19 | 126 |
8-May-19 | 127 |
9-May-19 | 128 |
10-May-19 | 129 |
11-May-19 | 130 |
12-May-19 | 131 |
13-May-19 | 132 |
14-May-19 | 133 |
15-May-19 | 134 |
16-May-19 | 135 |
17-May-19 | 136 |
18-May-19 | 137 |
19-May-19 | 138 |
20-May-19 | 139 |
21-May-19 | 140 |
22-May-19 | 141 |
23-May-19 | 142 |
24-May-19 | 143 |
25-May-19 | 144 |
26-May-19 | 145 |
27-May-19 | 146 |
28-May-19 | 147 |
29-May-19 | 148 |
30-May-19 | 149 |
31-May-19 | 150 |
1-Jun-19 | 151 |
2-Jun-19 | 152 |
3-Jun-19 | 153 |
4-Jun-19 | 154 |
5-Jun-19 | 155 |
6-Jun-19 | 156 |
7-Jun-19 | 157 |
8-Jun-19 | 158 |
9-Jun-19 | 159 |
10-Jun-19 | 160 |
11-Jun-19 | 161 |
12-Jun-19 | 162 |
13-Jun-19 | 163 |
14-Jun-19 | 164 |
15-Jun-19 | 165 |
16-Jun-19 | 166 |
17-Jun-19 | 167 |
18-Jun-19 | 168 |
19-Jun-19 | 169 |
20-Jun-19 | 170 |
21-Jun-19 | 171 |
22-Jun-19 | 172 |
23-Jun-19 | 173 |
24-Jun-19 | 174 |
25-Jun-19 | 175 |
26-Jun-19 | 176 |
27-Jun-19 | 177 |
28-Jun-19 | 178 |
29-Jun-19 | 179 |
30-Jun-19 | 180 |
1-Jul-19 | 181 |
2-Jul-19 | 182 |
3-Jul-19 | 183 |
4-Jul-19 | 184 |
5-Jul-19 | 185 |
6-Jul-19 | 186 |
7-Jul-19 | 187 |
8-Jul-19 | 188 |
9-Jul-19 | 189 |
10-Jul-19 | 190 |
11-Jul-19 | 191 |
12-Jul-19 | 192 |
13-Jul-19 | 193 |
14-Jul-19 | 194 |
15-Jul-19 | 195 |
16-Jul-19 | 196 |
17-Jul-19 | 197 |
18-Jul-19 | 198 |
19-Jul-19 | 199 |
20-Jul-19 | 200 |
21-Jul-19 | 201 |
22-Jul-19 | 202 |
23-Jul-19 | 203 |
24-Jul-19 | 204 |
25-Jul-19 | 205 |
26-Jul-19 | 206 |
27-Jul-19 | 207 |
28-Jul-19 | 208 |
29-Jul-19 | 209 |
30-Jul-19 | 210 |
31-Jul-19 | 211 |
1-Aug-19 | 212 |
2-Aug-19 | 213 |
3-Aug-19 | 214 |
4-Aug-19 | 215 |
5-Aug-19 | 216 |
6-Aug-19 | 217 |
7-Aug-19 | 218 |
8-Aug-19 | 219 |
9-Aug-19 | 220 |
10-Aug-19 | 221 |
11-Aug-19 | 222 |
12-Aug-19 | 223 |
13-Aug-19 | 224 |
14-Aug-19 | 225 |
15-Aug-19 | 226 |
16-Aug-19 | 227 |
17-Aug-19 | 228 |
18-Aug-19 | 229 |
19-Aug-19 | 230 |
20-Aug-19 | 231 |
21-Aug-19 | 232 |
22-Aug-19 | 233 |
23-Aug-19 | 234 |
24-Aug-19 | 235 |
25-Aug-19 | 236 |
26-Aug-19 | 237 |
27-Aug-19 | 238 |
I need this data in the following form:
Date | Balance | Date -1 | Balance | Date -2 | Balance | Date -3 | Balance |
1-Aug-19 | 212 | 1-Jul-19 | 181 | 1-Jun-19 | 151 | 1-May-19 | 120 |
2-Aug-19 | 213 | 2-Jul-19 | 182 | 2-Jun-19 | 152 | 2-May-19 | 121 |
3-Aug-19 | 214 | 3-Jul-19 | 183 | 3-Jun-19 | 153 | 3-May-19 | 122 |
4-Aug-19 | 215 | 4-Jul-19 | 184 | 4-Jun-19 | 154 | 4-May-19 | 123 |
5-Aug-19 | 216 | 5-Jul-19 | 185 | 5-Jun-19 | 155 | 5-May-19 | 124 |
6-Aug-19 | 217 | 6-Jul-19 | 186 | 6-Jun-19 | 156 | 6-May-19 | 125 |
7-Aug-19 | 218 | 7-Jul-19 | 187 | 7-Jun-19 | 157 | 7-May-19 | 126 |
8-Aug-19 | 219 | 8-Jul-19 | 188 | 8-Jun-19 | 158 | 8-May-19 | 127 |
9-Aug-19 | 220 | 9-Jul-19 | 189 | 9-Jun-19 | 159 | 9-May-19 | 128 |
10-Aug-19 | 221 | 10-Jul-19 | 190 | 10-Jun-19 | 160 | 10-May-19 | 129 |
11-Aug-19 | 222 | 11-Jul-19 | 191 | 11-Jun-19 | 161 | 11-May-19 | 130 |
12-Aug-19 | 223 | 12-Jul-19 | 192 | 12-Jun-19 | 162 | 12-May-19 | 131 |
13-Aug-19 | 224 | 13-Jul-19 | 193 | 13-Jun-19 | 163 | 13-May-19 | 132 |
14-Aug-19 | 225 | 14-Jul-19 | 194 | 14-Jun-19 | 164 | 14-May-19 | 133 |
15-Aug-19 | 226 | 15-Jul-19 | 195 | 15-Jun-19 | 165 | 15-May-19 | 134 |
16-Aug-19 | 227 | 16-Jul-19 | 196 | 16-Jun-19 | 166 | 16-May-19 | 135 |
17-Aug-19 | 228 | 17-Jul-19 | 197 | 17-Jun-19 | 167 | 17-May-19 | 136 |
18-Aug-19 | 229 | 18-Jul-19 | 198 | 18-Jun-19 | 168 | 18-May-19 | 137 |
19-Aug-19 | 230 | 19-Jul-19 | 199 | 19-Jun-19 | 169 | 19-May-19 | 138 |
20-Aug-19 | 231 | 20-Jul-19 | 200 | 20-Jun-19 | 170 | 20-May-19 | 139 |
21-Aug-19 | 232 | 21-Jul-19 | 201 | 21-Jun-19 | 171 | 21-May-19 | 140 |
22-Aug-19 | 233 | 22-Jul-19 | 202 | 22-Jun-19 | 172 | 22-May-19 | 141 |
23-Aug-19 | 234 | 23-Jul-19 | 203 | 23-Jun-19 | 173 | 23-May-19 | 142 |
24-Aug-19 | 235 | 24-Jul-19 | 204 | 24-Jun-19 | 174 | 24-May-19 | 143 |
25-Aug-19 | 236 | 25-Jul-19 | 205 | 25-Jun-19 | 175 | 25-May-19 | 144 |
26-Aug-19 | 237 | 26-Jul-19 | 206 | 26-Jun-19 | 176 | 26-May-19 | 145 |
27-Aug-19 | 238 | 27-Jul-19 | 207 | 27-Jun-19 | 177 | 27-May-19 | 146 |
28-Jul-19 | 208 | 28-Jun-19 | 178 | 28-May-19 | 147 | ||
29-Jul-19 | 209 | 29-Jun-19 | 179 | 29-May-19 | 148 | ||
30-Jul-19 | 210 | 30-Jun-19 | 180 | 30-May-19 | 149 | ||
31-Jul-19 | 211 | 31-May-19 | 150 |
I need to do this using DAX. Is there any way to do this?
Solved! Go to Solution.
Hi @shubh25,
We can create such a table using such DAX, but it still need to modify if you have more than 4 months.
Comparative = VAR maxDate = MAX ( Data[Date] ) VAR minDate = MIN ( Data[Date] ) VAR maxMonth = MONTH ( MAX ( Data[Date] ) ) VAR minMonth = MONTH ( MIN ( Data[Date] ) ) VAR t1 = ADDCOLUMNS ( CALENDAR ( DATE ( 2019, maxMonth, 1 ), maxDate ), "Balance", LOOKUPVALUE ( Data[Balance], Data[Date], [Date] ), "DayKey", DAY ( [Date] ) ) VAR d2 = DATE ( 2019, maxMonth - 1, 1 ) VAR t2 = ADDCOLUMNS ( CALENDAR ( d2, DATE ( 2019, MONTH ( d2 ), SWITCH ( MONTH ( d2 ), 1, 31, 2, 28, 3, 31, 4, 30, 5, 31, 6, 30, 7, 31, 8, 31, 9, 30, 10, 31, 11, 30, 12, 31 ) ) ), "Balance2", LOOKUPVALUE ( Data[Balance], Data[Date], [Date] ), "DayKey", DAY ( [Date] ) ) VAR t2r = SELECTCOLUMNS ( t2, "Date-1", [Date], "Balance2", [Balance2], "DayKey", [DayKey] ) VAR d3 = DATE ( 2019, maxMonth - 2, 1 ) VAR t3 = ADDCOLUMNS ( CALENDAR ( d3, DATE ( 2019, MONTH ( d3 ), SWITCH ( MONTH ( d3 ), 1, 31, 2, 28, 3, 31, 4, 30, 5, 31, 6, 30, 7, 31, 8, 31, 9, 30, 10, 31, 11, 30, 12, 31 ) ) ), "Balance3", LOOKUPVALUE ( Data[Balance], Data[Date], [Date] ), "DayKey", DAY ( [Date] ) ) VAR t3r = SELECTCOLUMNS ( t3, "Date-2", [Date], "Balance3", [Balance3], "DayKey", [DayKey] ) VAR d4 = DATE ( 2019, maxMonth - 3, 1 ) VAR t4 = ADDCOLUMNS ( CALENDAR ( d4, DATE ( 2019, MONTH ( d4 ), SWITCH ( MONTH ( d4 ), 1, 31, 2, 28, 3, 31, 4, 30, 5, 31, 6, 30, 7, 31, 8, 31, 9, 30, 10, 31, 11, 30, 12, 31 ) ) ), "Balance4", LOOKUPVALUE ( Data[Balance], Data[Date], [Date] ), "DayKey", DAY ( [Date] ) ) VAR t4r = SELECTCOLUMNS ( t4, "Date-3", [Date], "Balance4", [Balance4], "DayKey", [DayKey] ) VAR result1 = NATURALLEFTOUTERJOIN ( t2r, t1 ) VAR result2 = NATURALLEFTOUTERJOIN ( result1, t3r ) VAR result3 = NATURALLEFTOUTERJOIN ( result2, t4r ) RETURN SELECTCOLUMNS ( result3, "Date", [Date], "Balance", [Balance], "Date-1", [Date-1], "Balance-1", [Balance2], "Date-2", [Date-2], "Balance-2", [Balance3], "Date-3", [Date-3], "Balance-3", [Balance4] )
BTW, pbix as attached.
Or we can use power query editor to do it , first copy the table into server same table depends on the number of month.
For each table, do the following steps
1. Add a column depends on the month
= Table.AddColumn(#"Changed Type", "Custom", each Date.MonthName([#"Date "]))
2. Pivot the table
= Table.Pivot(#"Added Custom", List.Distinct(#"Added Custom"[Custom]), "Custom", "Balance", List.Sum)
3. Using filter to select row for each month
= Table.SelectRows(#"Pivoted Column", each ([May] <> null))
4. Remove unnessary column
= Table.RemoveColumns(#"Filtered Rows",{"June", "July", "August"})
5. Add index
= Table.AddIndexColumn(#"Removed Columns", "Index", 1, 1)
6.Then use the nestjoin to each two tables
= Table.NestedJoin(#"Table (2)", {"Index"}, #"Table (3)", {"Index"}, "Table (3)", JoinKind.LeftOuter) = Table.ExpandTableColumn(Source, "Table (3)", {"Date ", "June"}, {"Table (3).Date ", "Table (3).June"})
7. At last, remove the index column
= Table.RemoveColumns(#"Expanded Table (5)",{"Index"})
8. Finally, we can get the result as your requirement
BTW, pbix as attached.
Community Support Team _ DongLi
If this post helps, then please consider Accept it as the solution to help the other members find it more
Hi @shubh25,
We can create such a table using such DAX, but it still need to modify if you have more than 4 months.
Comparative = VAR maxDate = MAX ( Data[Date] ) VAR minDate = MIN ( Data[Date] ) VAR maxMonth = MONTH ( MAX ( Data[Date] ) ) VAR minMonth = MONTH ( MIN ( Data[Date] ) ) VAR t1 = ADDCOLUMNS ( CALENDAR ( DATE ( 2019, maxMonth, 1 ), maxDate ), "Balance", LOOKUPVALUE ( Data[Balance], Data[Date], [Date] ), "DayKey", DAY ( [Date] ) ) VAR d2 = DATE ( 2019, maxMonth - 1, 1 ) VAR t2 = ADDCOLUMNS ( CALENDAR ( d2, DATE ( 2019, MONTH ( d2 ), SWITCH ( MONTH ( d2 ), 1, 31, 2, 28, 3, 31, 4, 30, 5, 31, 6, 30, 7, 31, 8, 31, 9, 30, 10, 31, 11, 30, 12, 31 ) ) ), "Balance2", LOOKUPVALUE ( Data[Balance], Data[Date], [Date] ), "DayKey", DAY ( [Date] ) ) VAR t2r = SELECTCOLUMNS ( t2, "Date-1", [Date], "Balance2", [Balance2], "DayKey", [DayKey] ) VAR d3 = DATE ( 2019, maxMonth - 2, 1 ) VAR t3 = ADDCOLUMNS ( CALENDAR ( d3, DATE ( 2019, MONTH ( d3 ), SWITCH ( MONTH ( d3 ), 1, 31, 2, 28, 3, 31, 4, 30, 5, 31, 6, 30, 7, 31, 8, 31, 9, 30, 10, 31, 11, 30, 12, 31 ) ) ), "Balance3", LOOKUPVALUE ( Data[Balance], Data[Date], [Date] ), "DayKey", DAY ( [Date] ) ) VAR t3r = SELECTCOLUMNS ( t3, "Date-2", [Date], "Balance3", [Balance3], "DayKey", [DayKey] ) VAR d4 = DATE ( 2019, maxMonth - 3, 1 ) VAR t4 = ADDCOLUMNS ( CALENDAR ( d4, DATE ( 2019, MONTH ( d4 ), SWITCH ( MONTH ( d4 ), 1, 31, 2, 28, 3, 31, 4, 30, 5, 31, 6, 30, 7, 31, 8, 31, 9, 30, 10, 31, 11, 30, 12, 31 ) ) ), "Balance4", LOOKUPVALUE ( Data[Balance], Data[Date], [Date] ), "DayKey", DAY ( [Date] ) ) VAR t4r = SELECTCOLUMNS ( t4, "Date-3", [Date], "Balance4", [Balance4], "DayKey", [DayKey] ) VAR result1 = NATURALLEFTOUTERJOIN ( t2r, t1 ) VAR result2 = NATURALLEFTOUTERJOIN ( result1, t3r ) VAR result3 = NATURALLEFTOUTERJOIN ( result2, t4r ) RETURN SELECTCOLUMNS ( result3, "Date", [Date], "Balance", [Balance], "Date-1", [Date-1], "Balance-1", [Balance2], "Date-2", [Date-2], "Balance-2", [Balance3], "Date-3", [Date-3], "Balance-3", [Balance4] )
BTW, pbix as attached.
Or we can use power query editor to do it , first copy the table into server same table depends on the number of month.
For each table, do the following steps
1. Add a column depends on the month
= Table.AddColumn(#"Changed Type", "Custom", each Date.MonthName([#"Date "]))
2. Pivot the table
= Table.Pivot(#"Added Custom", List.Distinct(#"Added Custom"[Custom]), "Custom", "Balance", List.Sum)
3. Using filter to select row for each month
= Table.SelectRows(#"Pivoted Column", each ([May] <> null))
4. Remove unnessary column
= Table.RemoveColumns(#"Filtered Rows",{"June", "July", "August"})
5. Add index
= Table.AddIndexColumn(#"Removed Columns", "Index", 1, 1)
6.Then use the nestjoin to each two tables
= Table.NestedJoin(#"Table (2)", {"Index"}, #"Table (3)", {"Index"}, "Table (3)", JoinKind.LeftOuter) = Table.ExpandTableColumn(Source, "Table (3)", {"Date ", "June"}, {"Table (3).Date ", "Table (3).June"})
7. At last, remove the index column
= Table.RemoveColumns(#"Expanded Table (5)",{"Index"})
8. Finally, we can get the result as your requirement
BTW, pbix as attached.
Community Support Team _ DongLi
If this post helps, then please consider Accept it as the solution to help the other members find it more
Hi @v-lid-msft ,
This worked a charm and also gave me many ideas for future exercises. I added a date column to make it a little dynamic. Also, that is a really creative way to use switch in calender function.
Thank you for your effort.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
119 | |
78 | |
58 | |
52 | |
46 |
User | Count |
---|---|
170 | |
117 | |
63 | |
58 | |
51 |