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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
parry2k
Super User
Super User

calculated % of total based on one row, apply % to all other rows

hi there,

 

Just interesting question here. So I have a transaction table with product , category, amount and another table called category and both table are related on category.

 

IN transaction table, not all the products have category, only one product id has categor record. What I'm looking for is to sum all the maount of this one product and calculate share by category. and then apply that share of each category to other products in transaciton table.

 

In following example A1 the main product with categor and share is calculate for each category from total amount of product A1

 

and same % is now applied to rest of the products to show amount by category (right hand side pivot table)

 

 

See image below (i put this as a sample)category share.PNG

 

 



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

5 REPLIES 5
v-jiascu-msft
Employee
Employee

Hi @parry2k,

 

Could you please mark the proper answer as solution or share the answer if it's convenient for you? That will be a help to the others.

 

Best Regards!
Dale

Community Support Team _ Dale
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Hi Dale,

 

Thanks for the follow up. I don't think I received the solution yet and hoping someone will help me here.

 

P



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

Hi @parry2k,

 

If you want to try @danextian 's method, you only need to do one step more, which is adding a calculated column. It works.

NewAmount =
CALCULATE ( SUM ( 'Final'[Amount] ), ALLEXCEPT ( 'Final', 'Final'[Product] ) )
    * [Share]

Or, you can try this method.

1. Add an index in Query Editor. (must start from 0).

2. Add a new calculated column.

 

NewCategory =
VAR currentIndex = 'Transaction'[Index]
RETURN
    CALCULATE (
        VALUES ( 'Transaction'[Category] ),
        FILTER (
            'Transaction',
            'Transaction'[Product] = "A1"
                && 'Transaction'[Index] = MOD ( currentIndex, 5 )
        )
    )

calculated % of total based on one row, apply % to all other rows.jpg

 

 

 

 

 

 

 

 

 

 

 

 

3. Create a measure.

Values =
VAR ratio =
    DIVIDE (
        CALCULATE ( SUM ( 'Transaction'[Amount] ), 'Transaction'[Product] = "A1" ),
        CALCULATE (
            SUM ( 'Transaction'[Amount] ),
            FILTER ( ALL ( 'Transaction' ), 'Transaction'[Product] = "A1" )
        ),
        0
    )
RETURN
    CALCULATE (
        SUM ( 'Transaction'[Amount] ),
        ALLEXCEPT ( 'Transaction', 'Transaction'[Product] )
    )
        * ratio

4. Create a visual Matrix.

 

calculated % of total based on one row, apply % to all other rows1.jpg

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

If it helped, please mark the proper answer as solution.

Best Regards!

Dale

Community Support Team _ Dale
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
danextian
Super User
Super User

By the way, here are my codes

 

Original

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ZYxJCoAwEAT/EvAmYZZE49HtFcH/f8MhBhntQwdS1dO1hpXDGFYLE9k7xWkewjV2sVmkCdao6sxu0WaEIpEzhyU95rd2WnIz6tbE/q/4oISIefkjwZY6pH0rA8rYYgE0Y8vPJ2x1VBAtBe4KlLjfXTc=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Product = _t, Category = _t, Amount = _t, Share = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Product", type text}, {"Category", type text}, {"Amount", Int64.Type}, {"Share", Percentage.Type}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 1, 1),
    #"Added Custom" = Table.AddColumn(#"Added Index", "Index 1-5", each if Number.From(Text.End(Number.ToText([Index]),1)) = 0 then 5
else 

if Number.From(Text.End(Number.ToText([Index]),1))<=5 then
Number.From(Text.End(Number.ToText([Index]),1)) else

Number.From(Text.End(Number.ToText([Index]),1))-5, type number)
in
    #"Added Custom"

 

Halfway

 

let
    Source = original,
    #"Filtered Rows" = Table.SelectRows(Source, each [Category] <> null and [Category] <> ""),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Amount"})
in
    #"Removed Columns"

 

Final

let
    Source = original,
    #"Removed Columns" = Table.RemoveColumns(Source,{"Category", "Share", "Index"}),
    #"Merged Queries" = Table.NestedJoin(#"Removed Columns",{"Index 1-5"},halfway,{"Index 1-5"},"halfway",JoinKind.LeftOuter),
    #"Expanded halfway" = Table.ExpandTableColumn(#"Merged Queries", "halfway", {"Category", "Share"}, {"Category", "Share"})
in
    #"Expanded halfway"





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




"Tell me and I’ll forget; show me and I may remember; involve me and I’ll understand."
Need Power BI consultation, get in touch with me on LinkedIn or hire me on UpWork.
Learn with me on YouTube @DAXJutsu.
danextian
Super User
Super User

Hi @parry2k,

 

I would have three separate queries for this: the original query and two others that reference to the original

 

Original 

  • Add an index column starting at one
  • Add a custom column with the following formula:  

 

if Number.From(Text.End(Number.ToText([Index]),1)) = 0 then 5
else
if Number.From(Text.End(Number.ToText([Index]),1))<=5 then
Number.From(Text.End(Number.ToText([Index]),1)) else
Number.From(Text.End(Number.ToText([Index]),1))-5

 

  • Change the custom column type to number

This will create a column with numbers that repeat from 1 to 5

 

Halfway:

  • Remove blank rows from either category or share columns

Final

  • Remove Category, Share and Custom Column
  • Merge Halfway table with Final using custom column created in original
  • Expand table to show columns Category and Share
  • Then do additional necessary data shaping.





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




"Tell me and I’ll forget; show me and I may remember; involve me and I’ll understand."
Need Power BI consultation, get in touch with me on LinkedIn or hire me on UpWork.
Learn with me on YouTube @DAXJutsu.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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