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

Compete to become Power BI Data Viz World Champion! First round ends August 18th. Get started.

Reply
paul_luvaglia
New Member

New Table - Calendar and Summarize

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

2 ACCEPTED SOLUTIONS
Anonymous
Not applicable

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:

vtianyichmsft_0-1718850232455.png

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.

View solution in original post

@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

 



Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
DAX For Humans

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

4 REPLIES 4
paul_luvaglia
New Member

This would be a quick example of the source

YearMonth

Inv Num

PartQty
20241

1

ABC4
202422ABC6
202423XYZ4
202444ABC1

 

I would like some thing as per the below

 

YearMonthPartQty
20241ABC4
20242ABC6
20243ABC

0

20244ABC1
20241XYZ0
20242XYZ0
20243XYZ4
20244XYZ0

 

@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

 



Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
DAX For Humans

DAX is easy, CALCULATE makes DAX hard...
Anonymous
Not applicable

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:

vtianyichmsft_0-1718850232455.png

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.

Greg_Deckler
Community Champion
Community Champion

@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.



Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
DAX For Humans

DAX is easy, CALCULATE makes DAX hard...

Helpful resources

Announcements
July PBI25 Carousel

Power BI Monthly Update - July 2025

Check out the July 2025 Power BI update to learn about new features.

August 2025 community update carousel

Fabric Community Update - August 2025

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