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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register 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
Community Champion
Community Champion

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], ";")

Full Power BI Video 20 Hours YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube
AlB
Community Champion
Community Champion

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
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

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

June 2025 community update carousel

Fabric Community Update - June 2025

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