cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
Private Helper I
Helper I

Occurrence of value (or) count value(text) in a column

Hi,

I'm trying to calculate the occurence of products in a column .Below is the table:

Products

a,b

b

c,a

d

 

Expected Result:

Products

Count_prod

a

2

b

2

c

1

d

1

Can we achieve this in DAX (or) power query? Thanks in advance for the help!!

1 ACCEPTED SOLUTION

Accepted Solutions
Community Support
Community Support

Re: Occurrence of value (or) count value(text) in a column

HI @Private,

You can use the following formula to create a new calculated table based on the original table products field:

 

NEW Table =
VAR _path =
    SUBSTITUTE (
        CONCATENATEX ( ALL ( 'Table'[Products] ), [Products], "," ),
        ",",
        "|"
    )
VAR _length =
    PATHLENGTH ( _path )
VAR _pathtable =
    ADDCOLUMNS (
        GENERATESERIES ( 1, _length, 1 ),
        "Product", PATHITEM ( _path, [Value] )
    )
RETURN
    ADDCOLUMNS (
        SUMMARIZE ( _pathtable, [Product] ),
        "Count", COUNTROWS ( FILTER ( _pathtable, [Product] = EARLIER ( [Product] ) ) )
    )

 

21.png

Reference link:

DAX how split a string by delimiter into a list or array? 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin Sheng
If this post helps, please consider Accept it as the solution to help the other members find it more quickly
Learning resources: Power BI

View solution in original post

4 REPLIES 4
Super User IV
Super User IV

Re: Occurrence of value (or) count value(text) in a column

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCijKTylNLilWitWJVkrUSQLTEDJZJxFMpyjFxgIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [#"(blank)" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"(blank)", type text}}),
    #"Promoted Headers" = Table.PromoteHeaders(#"Changed Type", [PromoteAllScalars=true]),
    #"Changed Type1" = Table.TransformColumnTypes(#"Promoted Headers",{{"Products", type text}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type1", "Products", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Products.1", "Products.2"}),
    #"Changed Type2" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Products.1", type text}, {"Products.2", type text}}),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type2", {}, "Attribute", "Value"),
    #"Removed Columns" = Table.RemoveColumns(#"Unpivoted Columns",{"Attribute"}),
    #"Grouped Rows" = Table.Group(#"Removed Columns", {"Value"}, {{"Count", each Table.RowCount(_), type number}})
in
    #"Grouped Rows"

---------------------------------------

Putting square pegs in round holes since 1972.

I have a NEW book! 
DAX Cookbook from Packt
Over 120 DAX Recipes!
Did I answer your question? Mark my post as a solution!

Proud to be a Datanaut!

Super User IV
Super User IV

Re: Occurrence of value (or) count value(text) in a column

@Private or you can try this, if you don't want to group in power query, remove last step and then with DAX you can group  by product

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCijKTylNLilWitWJVkrUSQLTEDJZJxFMpyjFxgIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [#"(blank)" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"(blank)", type text}}),
    #"Promoted Headers" = Table.PromoteHeaders(#"Changed Type", [PromoteAllScalars=true]),
    #"Changed Type1" = Table.TransformColumnTypes(#"Promoted Headers",{{"Products", type text}}),
    #"Split Column by Delimiter" = Table.ExpandListColumn(Table.TransformColumns(#"Changed Type1", {{"Products", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), let itemType = (type nullable text) meta [Serialized.Text = true] in type {itemType}}}), "Products"),
    #"Grouped Rows" = Table.Group(#"Split Column by Delimiter", {"Products"}, {{"Count", each Table.RowCount(_), type number}})
in
    #"Grouped Rows"

 






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

Proud to be a Datanaut! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.





Community Support
Community Support

Re: Occurrence of value (or) count value(text) in a column

HI @Private,

You can use the following formula to create a new calculated table based on the original table products field:

 

NEW Table =
VAR _path =
    SUBSTITUTE (
        CONCATENATEX ( ALL ( 'Table'[Products] ), [Products], "," ),
        ",",
        "|"
    )
VAR _length =
    PATHLENGTH ( _path )
VAR _pathtable =
    ADDCOLUMNS (
        GENERATESERIES ( 1, _length, 1 ),
        "Product", PATHITEM ( _path, [Value] )
    )
RETURN
    ADDCOLUMNS (
        SUMMARIZE ( _pathtable, [Product] ),
        "Count", COUNTROWS ( FILTER ( _pathtable, [Product] = EARLIER ( [Product] ) ) )
    )

 

21.png

Reference link:

DAX how split a string by delimiter into a list or array? 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin Sheng
If this post helps, please consider Accept it as the solution to help the other members find it more quickly
Learning resources: Power BI

View solution in original post

Private Helper I
Helper I

Re: Occurrence of value (or) count value(text) in a column

@v-shex-msftThanks this works. To add up further, If there's a scenario where we have multiple columns and want to rollup subtotals like one below can we use the same formula? :

Sales Table:

NameProducts
Toma,b
Harryb
Tomc, a
Potterd

 

Expected Result:

 
ProductsCount_prod
A2
Tom1
Tom1
B2
Harry1
Tom1
C1
Tom1
D1
Potter1
 

Helpful resources

Announcements
Announcing the New Spanish Forum

Announcing the New Spanish Forum

Do you need help in Spanish? Check out our new Spanish community section.

MBAS Gallery 2020

MBAS Gallery 2020

Watch Microsoft Business Applications Summit sessions on-demand.

‘Better Together’ Integration Forum Launch

‘Better Together’ Integration Forum Launch

We've launched a how-to forum where you can learn about how Power BI integrates with other Power Platform products.

Top Solution Authors
Top Kudoed Authors