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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
mudassirmir
New Member

Summarize weekly production in monthly buckets

Hi There,

 

I have production table in below format and i am trying to workout how to put production quantities in monthly buckets. In below example production falls in two months. I want output to show we produced 2600 in Oct (18200/7) and rest of the qty in Nov.

 

Production StartProduction EndProduction Qty
31/10/202206/11/202218200

 

Thanks in advance for your help.

1 REPLY 1
ImkeF
Super User
Super User

Hi @mudassirmir ,

you can use the function I've published here to create a list of days that allow you to allocate accordingly: 
Date.DatesBetween to retrieve dates between 2 dates in Power BI and Power Query – The BIccountant
After that, the count of the items in your list can be used as a divisor to create the daily amount. 
Then expand the days, apply the daily amount calculation and aggregate to month, to your liking:
(Please also check the file enclosed):

 

let
    Source = Table.FromRows(
        Json.Document(
            Binary.Decompress(
                Binary.FromText("i45WMjbUNzTQNzIwMlLSUTLTNzSEsQ0tjAwMlGJjAQ==", BinaryEncoding.Base64),
                Compression.Deflate
            )
        ),
        let
            _t = ((type nullable text) meta [Serialized.Text = true])
        in
            type table [#"Production Start" = _t, #"Production End" = _t, #"Production Qty" = _t]
    ),
    #"Changed Type" = Table.TransformColumnTypes(
        Source,
        {{"Production Start", type date}, {"Production End", type date}, {"Production Qty", Int64.Type}},
        "en-GB"
    ),
    #"Invoked Custom Function" = Table.AddColumn(
        #"Changed Type",
        "Dates",
        each fnDatesBetween([Production Start], [Production End], "Day")
    ),
    #"Added Custom" = Table.AddColumn(#"Invoked Custom Function", "Divisor", each List.Count([Dates])),
    #"Expanded Dates" = Table.ExpandListColumn(#"Added Custom", "Dates"),
                                                                                                                                                                     
    #"Inserted Division" = Table.AddColumn(
        #"Expanded Dates",
        "DailyAmount",
        each [Production Qty] / [Divisor],
        type number
    ),
    // I would stop here and load the data as it is into the data model to stay flexible. But if you are sure that you only want on monthly level, continue with the grouping.     
    #"Calculated Start of Month" = Table.TransformColumns(
        #"Inserted Division",
        {{"Dates", Date.StartOfMonth, type date}}
    ),
    #"Grouped Rows" = Table.Group(
        #"Calculated Start of Month",
        {"Dates"},
        {{"MonthlyAmount", each List.Sum([DailyAmount]), type number}}
    )
in
    #"Grouped Rows"

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Helpful resources

Announcements
Europe Fabric Conference

Europe’s largest Microsoft Fabric Community Conference

Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.

July 2024 Power BI Update

Power BI Monthly Update - July 2024

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

July Newsletter

Fabric Community Update - July 2024

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

Top Solution Authors
Top Kudoed Authors