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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
mattpowerbiuser
Regular Visitor

Metric to sum the first value within each group

Hello, we have a dataset of animal biomass inventory at the end of each month for several groups of cultivated animals. We need to create reports to show the proportion of starting inventory that was harvested during each period. Therefore, we need to have the "starting" inventory (and also would like to have the "ending" inventory). New groups may enter inventory during the middle of the year, and we need the "starting" inventory at the first date the group entered inventory. So If the group entered inventory in June 2021, we need the "starting inventory" of the year 2021 to be the value at the end of June. So I believe we need to sum the first nonblank value of each group within each date context. 

Below is a sample dataset:

 

DateGroupBiomass
12/31/20A 
1/31/21A 
2/28/21A 
3/31/21A 
4/30/21A 
5/31/21A 
6/30/21A100
7/31/21A90
8/31/21A80
9/30/21A70
10/31/21A60
11/30/21A50
12/31/21A40
12/31/20B200
1/31/21B180
2/28/21B160
3/31/21B140
4/30/21B120
5/31/21B100
6/30/21B80
7/31/21B60
8/31/21B40
9/30/21B20
10/31/21B0
11/30/21B0
12/31/21B0

 

The results should look as follows:

 

 2021
Group A 
Starting Biomass100
Ending Biomass40
Group B 
Starting Biomass200
Ending Biomass0
Total 
Starting Biomass300
Ending Biomass40

 

Your assistance is greatly appreciated.

 

2 ACCEPTED SOLUTIONS
Bujor
Frequent Visitor

Starting Biomass =
    FIRSTNONBLANKVALUE( 'Table'[Date], SUM( 'Table'[Biomass] ) )
 
Ending Biomass =
    LASTNONBLANKVALUE( 'Table'[Date], SUM( 'Table'[Biomass] ) )
 
If these measures are used, then the starting & ending og Group B are 180 and 0, respectively.

View solution in original post

mattpowerbiuser
Regular Visitor

Unfortunately the above solutions don't take into account that each group has a different balance at the end of each period. The balance must be found for each group and then summed. It took me several months to figure out, but finally getting a copy of DAX Patterns as well as suggestions from ChatGPT, I was able to verify that the solution below works:

InitialB = 
VAR myDate =
IF(
    ISBLANK(
        CALCULATE(LASTNONBLANK(FactTable[Date],0),
        FILTER(
            ALL('Date'), 
            YEAR('Date'[Date]) = YEAR(MIN('Date'[Date]) - 1)
        )
        )
    ),
    FIRSTNONBLANK(FactTable[Date],0),
    CALCULATE(
        LASTNONBLANK(FactTable[Date], 0),
        FILTER(
            ALL('Date'),
            YEAR('Date'[Date]) = YEAR(MIN('Date'[Date])) - 1
        )
    )
)

VAR MaxBalanceDates = 
ADDCOLUMNS(
    SUMMARIZE(FactTable,FactTable[Group]),
    "BalDate",
   myDate
)

VAR MaxBalanceDatesWithLineage =
    TREATAS(MaxBalanceDates, FactTable[Group], 'Date'[Date])
VAR Result =
    CALCULATE(SUM(FactTable[B (kg)]), MaxBalanceDatesWithLineage)
RETURN
    Result

Note that the measure has a special feature where if there is no available balance at the end of the prior period, use the first available balance during the filter context. E.g. if animals are born during the middle of the year, their initial balance for the year is the first available balance.

View solution in original post

2 REPLIES 2
mattpowerbiuser
Regular Visitor

Unfortunately the above solutions don't take into account that each group has a different balance at the end of each period. The balance must be found for each group and then summed. It took me several months to figure out, but finally getting a copy of DAX Patterns as well as suggestions from ChatGPT, I was able to verify that the solution below works:

InitialB = 
VAR myDate =
IF(
    ISBLANK(
        CALCULATE(LASTNONBLANK(FactTable[Date],0),
        FILTER(
            ALL('Date'), 
            YEAR('Date'[Date]) = YEAR(MIN('Date'[Date]) - 1)
        )
        )
    ),
    FIRSTNONBLANK(FactTable[Date],0),
    CALCULATE(
        LASTNONBLANK(FactTable[Date], 0),
        FILTER(
            ALL('Date'),
            YEAR('Date'[Date]) = YEAR(MIN('Date'[Date])) - 1
        )
    )
)

VAR MaxBalanceDates = 
ADDCOLUMNS(
    SUMMARIZE(FactTable,FactTable[Group]),
    "BalDate",
   myDate
)

VAR MaxBalanceDatesWithLineage =
    TREATAS(MaxBalanceDates, FactTable[Group], 'Date'[Date])
VAR Result =
    CALCULATE(SUM(FactTable[B (kg)]), MaxBalanceDatesWithLineage)
RETURN
    Result

Note that the measure has a special feature where if there is no available balance at the end of the prior period, use the first available balance during the filter context. E.g. if animals are born during the middle of the year, their initial balance for the year is the first available balance.

Bujor
Frequent Visitor

Starting Biomass =
    FIRSTNONBLANKVALUE( 'Table'[Date], SUM( 'Table'[Biomass] ) )
 
Ending Biomass =
    LASTNONBLANKVALUE( 'Table'[Date], SUM( 'Table'[Biomass] ) )
 
If these measures are used, then the starting & ending og Group B are 180 and 0, respectively.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors