Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Hi,
A Contract has a Startdate, Enddate and a period how many times there is a payment (year, quarter, month)
I want to know when a future payment is expected.
Somebody a fantastic idea to solve this question?
Contract | Amount | Period | Startdate | Enddate | Result | jan-21 | feb-21 | mrt-21 | apr-21 | mei-21 | jun-21 | jul-21 | aug-21 | sep-21 | okt-21 | nov-21 | dec-21 | jan-22 | feb-22 | mrt-22 | apr-22 | |
A | € 100,00 | Year | 1-3-2021 | € 100,00 | € 100,00 | |||||||||||||||||
B | € 150,00 | Quarter | 15-2-2021 | 31-12-2021 | € 150,00 | € 150,00 | € 150,00 | € 150,00 | ||||||||||||||
C | € 75,00 | Month | 13-1-2021 | 16-9-2021 | € 75,00 | € 75,00 | € 75,00 | € 75,00 | € 75,00 | € 75,00 | € 75,00 | € 75,00 | € 75,00 | |||||||||
D | € 85,00 | Month | 1-5-2021 | € 85,00 | € 85,00 | € 85,00 | € 85,00 | € 85,00 | € 85,00 | € 85,00 | € 85,00 | € 85,00 | € 85,00 | € 85,00 | € 85,00 |
I'm very curious
with kind regards
Solved! Go to Solution.
Hey @Anonymous ,
I use this DAX statement to create a table
Fact Projection =
var CalendarMax = MAX( 'Calendar'[Date] )
var fact =
SELECTCOLUMNS(
GENERATE(
'Billing'
, var ContractStart = 'Billing'[Begindate]
var ContractEnd = IF(ISBLANK('Billing'[Untildate]) , CalendarMax , 'Billing'[Untildate] )
var MonthUntilContractEnd = DATEDIFF( ContractStart , ContractEnd , MONTH )
var NoOfMonth =
SWITCH(
'Billing'[Period]
, "Month" , 1
, "Quarter" , 3
, "Year" , 12
)
return
ADDCOLUMNS(
GENERATESERIES( 1 , TRUNC( DIVIDE( MonthUntilContractEnd , NoOfMonth ) , 0) + 1 , 1 )
, "Date Projected" , DATE( YEAR( [Begindate] ) , MONTH( 'Billing'[Begindate] ) + ( [Value] - 1 ) * NoOfMonth , DAY( 'Billing'[Begindate] ) )
)
)
, "Contrac" , [Contract]
, "Amount" , [Amount]
, "Date Projected" , [Date Projected]
)
return
fact
This is how the relationships look like I created based on your sample file:
And this is how a matrix visual looks like
How it works
I create a table "Fact Projection" based on information of the billing table, the number of rows per contract is determined by the period of the contract and the end of the contract or if the end of the contract is missing by the end of the calendar. Basically the number of months is determined by an integer division, the number of months divided by the monhts that are forming the period.
Then I'm using this information to "calculate" the projection date. Very helpful is the following DAX
Date( 2021 , 1 + 12 , 11 )
Creates the date of the 11th of January 2022.
Hopefully this provides what you are looking for.
Regards,
Tom
Hey @Anonymous ,
here you will find a blog that describes my solution wih some more words:
Events and projections - Mincing Data - Gain Insight from Data (minceddata.info)
and here I create the additonal fact table using Power Query and some hacky M:
Events and projections, using M - Mincing Data - Gain Insight from Data (minceddata.info)
Maybe you will find this interesting.
Regards,
Tom
Hey @Anonymous ,
please prepare a pbix file with sample data, that still reflects your data model, at least the table that holds the contract information. Upload the file to onedrive or dropbox and share the link. If you are using an xlsx to prepare the sample data and share the link.
Regards,
Tom
Hey @Anonymous ,
I use this DAX statement to create a table
Fact Projection =
var CalendarMax = MAX( 'Calendar'[Date] )
var fact =
SELECTCOLUMNS(
GENERATE(
'Billing'
, var ContractStart = 'Billing'[Begindate]
var ContractEnd = IF(ISBLANK('Billing'[Untildate]) , CalendarMax , 'Billing'[Untildate] )
var MonthUntilContractEnd = DATEDIFF( ContractStart , ContractEnd , MONTH )
var NoOfMonth =
SWITCH(
'Billing'[Period]
, "Month" , 1
, "Quarter" , 3
, "Year" , 12
)
return
ADDCOLUMNS(
GENERATESERIES( 1 , TRUNC( DIVIDE( MonthUntilContractEnd , NoOfMonth ) , 0) + 1 , 1 )
, "Date Projected" , DATE( YEAR( [Begindate] ) , MONTH( 'Billing'[Begindate] ) + ( [Value] - 1 ) * NoOfMonth , DAY( 'Billing'[Begindate] ) )
)
)
, "Contrac" , [Contract]
, "Amount" , [Amount]
, "Date Projected" , [Date Projected]
)
return
fact
This is how the relationships look like I created based on your sample file:
And this is how a matrix visual looks like
How it works
I create a table "Fact Projection" based on information of the billing table, the number of rows per contract is determined by the period of the contract and the end of the contract or if the end of the contract is missing by the end of the calendar. Basically the number of months is determined by an integer division, the number of months divided by the monhts that are forming the period.
Then I'm using this information to "calculate" the projection date. Very helpful is the following DAX
Date( 2021 , 1 + 12 , 11 )
Creates the date of the 11th of January 2022.
Hopefully this provides what you are looking for.
Regards,
Tom
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
106 | |
99 | |
98 | |
38 | |
37 |
User | Count |
---|---|
158 | |
124 | |
75 | |
74 | |
63 |