Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.
Hi,
I have a table of sales data by invoice number and part number.
Each part may not be sold every month
I would like a summary table by part, year and month - but to include all year/month/part combinations even if we no invoices are in the source table for the year/month/part combination
How do I do this?
Many Thanks
Solved! Go to Solution.
Hi @paul_luvaglia ,
I think @Greg_Deckler โs solution is great!! just change the countrows to the aggregation you need depending on your needs. If it's just following the sample data you gave, you could probably just create a simple calculated column:
Column = IF([Qty]=BLANK(),[Qty]+0,[Qty])
An attachment for your reference. Hope it helps!
Best regards,
Community Support Team_ Scott Chang
If this post helps then please consider Accept it as the solution to help the other members find it more quickly.
@paul_luvaglia Sorry, got pulled away yesterday. If all you have is a single table, then you could do this tweak to the original formula. PBIX is attached below signature.
Table 2 =
VAR __Years = DISTINCT('Table'[Year])
VAR __Months = GENERATESERIES( MIN('Table'[Month]), MAX('Table'[Month]), 1 )
VAR __Parts = DISTINCT('Table'[Part])
VAR __Table =
ADDCOLUMNS(
CROSSJOIN(
CROSSJOIN( __Parts, __Years ),
__Months
),
"__Count",
VAR __Part = [Part]
VAR __Year = [Year]
VAR __Month = [Value]
VAR __Result = SUMX( FILTER( 'Table', [Part] = __Part && [Year] = __Year && [Month] = __Month ), [Qty]) + 0
RETURN
__Result
)
VAR __Result = SELECTCOLUMNS( __Table, "Part", [Part], "Year", [Year], "Month", [Value], "Count", [__Count] )
RETURN
__Result

@paul_luvaglia Try something like:
Table =
VAR __Years = DISTINCT('Table'[Year])
VAR __Months = DISTINCT('Table'[Month])
VAR __Parts = DISTINCT('Table'[Part])
VAR __Table =
ADDCOLUMNS(
CROSSJOIN(
CROSSJOIN( __Parts, __Years ),
__Months
),
"__Count",
VAR __Part = [Part]
VAR __Result = COUNTROWS( FILTER( 'Table', [Part] = __Part ) ) + 0
RETURN
__Result
)
RETURN
__Table
Otherwise, Sorry, having trouble following, can you post sample data as text and expected output?
Not really enough information to go on, please first check if your issue is a common issue listed here: https://community.powerbi.com/t5/Community-Blog/Before-You-Post-Read-This/ba-p/1116882
Also, please see this post regarding How to Get Your Question Answered Quickly: https://community.powerbi.com/t5/Community-Blog/How-to-Get-Your-Question-Answered-Quickly/ba-p/38490
The most important parts are:
1. Sample data as text, use the table tool in the editing bar
2. Expected output from sample data
3. Explanation in words of how to get from 1. to 2.

This would be a quick example of the source
| Year | Month | Inv Num | Part | Qty |
| 2024 | 1 | 1 | ABC | 4 |
| 2024 | 2 | 2 | ABC | 6 |
| 2024 | 2 | 3 | XYZ | 4 |
| 2024 | 4 | 4 | ABC | 1 |
I would like some thing as per the below
| Year | Month | Part | Qty |
| 2024 | 1 | ABC | 4 |
| 2024 | 2 | ABC | 6 |
| 2024 | 3 | ABC | 0 |
| 2024 | 4 | ABC | 1 |
| 2024 | 1 | XYZ | 0 |
| 2024 | 2 | XYZ | 0 |
| 2024 | 3 | XYZ | 4 |
| 2024 | 4 | XYZ | 0 |
Hi @paul_luvaglia ,
I think @Greg_Deckler โs solution is great!! just change the countrows to the aggregation you need depending on your needs. If it's just following the sample data you gave, you could probably just create a simple calculated column:
Column = IF([Qty]=BLANK(),[Qty]+0,[Qty])
An attachment for your reference. Hope it helps!
Best regards,
Community Support Team_ Scott Chang
If this post helps then please consider Accept it as the solution to help the other members find it more quickly.
@paul_luvaglia Sorry, got pulled away yesterday. If all you have is a single table, then you could do this tweak to the original formula. PBIX is attached below signature.
Table 2 =
VAR __Years = DISTINCT('Table'[Year])
VAR __Months = GENERATESERIES( MIN('Table'[Month]), MAX('Table'[Month]), 1 )
VAR __Parts = DISTINCT('Table'[Part])
VAR __Table =
ADDCOLUMNS(
CROSSJOIN(
CROSSJOIN( __Parts, __Years ),
__Months
),
"__Count",
VAR __Part = [Part]
VAR __Year = [Year]
VAR __Month = [Value]
VAR __Result = SUMX( FILTER( 'Table', [Part] = __Part && [Year] = __Year && [Month] = __Month ), [Qty]) + 0
RETURN
__Result
)
VAR __Result = SELECTCOLUMNS( __Table, "Part", [Part], "Year", [Year], "Month", [Value], "Count", [__Count] )
RETURN
__Result
