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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
ArunTiruveedula
Frequent Visitor

Creating measure on dimension table column without bi direction filtering

Hi All,

 

I am trying to create a measure based on Dimension Table Column using CONCATENATEX. Below is the simple example.

 

FACT_SALES  DIM_PRODUCT
DATEPRODUCT_KEYSALES_AMOUNT  PRODUCT_KEYPRODUCT_NAME
01/01/2020101100  101Pen
01/01/2020102500  102Box
01/01/2020103200  103Pencil
     104Scale
     105Bag

 

I need in the report output as below.

 

DateProducts SoldTotal Sales Measure
01/01/2020Pen; Box; Pencil800

 

But when I create measure Products Sold = CONCATENATEX(DIM_PRODUCT,'PRODUCT_NAME', ";") , I end up having all Products (Scale and Bag also) as I did not define Bi direction filter from Fact to Dimension.

 

Out put with above measure formula : (Not desired)

DateProducts SoldTotal Sales Measure
01/01/2020Pen; Box; Pencil ; Scale; Bag800

 

Please help how to handle it in DAX.

 

Thanks

1 ACCEPTED SOLUTION
AlB
Super User
Super User

Hi @ArunTiruveedula 

Try this

 

Products Sold =
VAR keys_ =
    DISTINCT ( FACT_SALES[PRODUCT_KEY] )
RETURN
    CONCATENATEX (
        FILTER ( ALL ( DIM_PRODUCT ), DIM_PRODUCT[PRODUCT_KEY] IN keys_ ),
        DIM_PRODUCT[PRODUCT_NAME],
        ", "
    )

 

or this

Products Sold V2 = 
VAR keys_ = DISTINCT ( FACT_SALES[PRODUCT_KEY] )
RETURN
    CONCATENATEX (
        CALCULATETABLE(  DIM_PRODUCT, TREATAS(keys_, DIM_PRODUCT[PRODUCT_KEY] )),
        DIM_PRODUCT[PRODUCT_NAME],
        ", "
    )

Please mark the question solved when done and consider giving a thumbs up if posts are helpful.

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

Cheers 

SU18_powerbi_badge

View solution in original post

3 REPLIES 3
wdx223_Daniel
Super User
Super User

@ArunTiruveedula try this

Product_Sod:=CONCATENATEX(SUMMARIZE(FACT_SALES,DIM_PRODUCT[PRODUCT_NAME]),DIM_PRODUCT[PRODUCT_NAME],",")

amitchandak
Super User
Super User

@ArunTiruveedula , Make sure two table have an active relation on product_key. The formaul seems correct. You can try

 

Products Sold = CONCATENATEX(values(DIM_PRODUCT['PRODUCT_NAME]),[PRODUCT_NAME], ";")

Join us as experts from around the world come together to shape the future of data and AI!
At the Microsoft Analytics Community Conference, global leaders and influential voices are stepping up to share their knowledge and help you master the latest in Microsoft Fabric, Copilot, and Purview.
️ November 12th-14th, 2024
 Online Event
Register Here
AlB
Super User
Super User

Hi @ArunTiruveedula 

Try this

 

Products Sold =
VAR keys_ =
    DISTINCT ( FACT_SALES[PRODUCT_KEY] )
RETURN
    CONCATENATEX (
        FILTER ( ALL ( DIM_PRODUCT ), DIM_PRODUCT[PRODUCT_KEY] IN keys_ ),
        DIM_PRODUCT[PRODUCT_NAME],
        ", "
    )

 

or this

Products Sold V2 = 
VAR keys_ = DISTINCT ( FACT_SALES[PRODUCT_KEY] )
RETURN
    CONCATENATEX (
        CALCULATETABLE(  DIM_PRODUCT, TREATAS(keys_, DIM_PRODUCT[PRODUCT_KEY] )),
        DIM_PRODUCT[PRODUCT_NAME],
        ", "
    )

Please mark the question solved when done and consider giving a thumbs up if posts are helpful.

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

Cheers 

SU18_powerbi_badge

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.