Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code FABINSIDER for a $400 discount.
Register nowThe Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.
I have a model I am building to compare Actual Sales Bookings from Salesforce vs Budget. The dimensional data from our actuals table is very robust as it leverages several key salesforce objects like opportunities and accounts. The plan data, however, is only constructed in excel and at a minimal granularity (Booking Event, Product Family, and Date). To Calculate the Plan Measure, I use the following formula:
Booking PL =
CALCULATE (
SWITCH (
[Selected Calculation],
1, SUM(FCT_PLAN_BOOKINGS[VALUE]),
2, CALCULATE ( SUM(FCT_PLAN_BOOKINGS[VALUE]), DATESQTD ( Periods[Date] ) ),
3, CALCULATE ( SUM(FCT_PLAN_BOOKINGS[VALUE]), DATESYTD ( Periods[Date] ) )
),
TREATAS(
SUMMARIZE(
FCT_SFDC_BOOKINGS,
FCT_SFDC_BOOKINGS[PRODUCT_FAMILY],
FCT_SFDC_BOOKINGS[BOOKING_SUMMARY],
FCT_SFDC_BOOKINGS[BOOKING_DATE]),
FCT_PLAN_BOOKINGS[PRODUCT_FAMILY],
FCT_PLAN_BOOKINGS[CATEGORY],
FCT_PLAN_BOOKINGS[DATE]
)
)
The Issue: When a given product family.booking_summary.date value is blank from the actuals (so effectively $0) , the measure above does not return the total Plan value.
Truncated Data Set ( FCT_PLAN_BOOKINGS)
Product Family | Date | Category | Value |
TR - MarketView | 6/1/2021 | Churn | (192,983.60) |
TR - Datagenic | 6/1/2021 | Churn | (6,077.66) |
Truncated Date Set (FCT_SFDC_BOOKINGS)
Product Family | Date | Booking_summary | Booking_value |
TR - MarketView | 6/1/2021 | Churn | (90,961.49) |
Sample Visual
As you can see, because the TR - Dategenic family doesn't have an actual, it filters out the Budget value.
Is there a modeling approach I am missing here?
Here is the current Data Model
I ended up utilizing SQLBI's guide for returning zero.
Creating this measure did the trick:
Booking Value =
VAR FirstBookingValue =
CALCULATE( MIN(FCT_SFDC_BOOKINGS[BOOKING_DATE]), ALLEXCEPT( FCT_SFDC_BOOKINGS, 'FCT_SFDC_BOOKINGS'[OPPORTUNITY_PRODUCT_NAME] ))
VAR LastBookingValue =
CALCULATE( MAX(FCT_SFDC_BOOKINGS[BOOKING_DATE]), REMOVEFILTERS())
VAR CurrentDate = MAX(Periods[Date])
VAR ForceZero = FirstBookingValue <= CurrentDate && CurrentDate <= LastBookingValue
VAR Amt = [Booking AC] + if (ForceZero, 0)
Return
Amt
@rstover_atx You could try replacing your big Treatas expression by these two
TREATAS( VALUES( FCT_SFDC_BOOKINGS[PRODUCT_FAMILY] ), FCT_PLAN_BOOKINGS[PRODUCT_FAMILY] ),
TREATAS( VALUES( FCT_SFDC_BOOKINGS[BOOKING_SUMMARY] ), FCT_PLAN_BOOKINGS[CATEGORY] )
Your TREATAS is incorrect syntactically. The measure should not even be accepted in PBI.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Check out the February 2025 Power BI update to learn about new features.
User | Count |
---|---|
85 | |
79 | |
54 | |
39 | |
35 |
User | Count |
---|---|
102 | |
80 | |
48 | |
48 | |
48 |