Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
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 | |||||
DATE | PRODUCT_KEY | SALES_AMOUNT | PRODUCT_KEY | PRODUCT_NAME | ||
01/01/2020 | 101 | 100 | 101 | Pen | ||
01/01/2020 | 102 | 500 | 102 | Box | ||
01/01/2020 | 103 | 200 | 103 | Pencil | ||
104 | Scale | |||||
105 | Bag |
I need in the report output as below.
Date | Products Sold | Total Sales Measure |
01/01/2020 | Pen; Box; Pencil | 800 |
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)
Date | Products Sold | Total Sales Measure |
01/01/2020 | Pen; Box; Pencil ; Scale; Bag | 800 |
Please help how to handle it in DAX.
Thanks
Solved! Go to Solution.
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
@ArunTiruveedula try this
Product_Sod:=CONCATENATEX(SUMMARIZE(FACT_SALES,DIM_PRODUCT[PRODUCT_NAME]),DIM_PRODUCT[PRODUCT_NAME],",")
@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], ";")
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
Check out the July 2025 Power BI update to learn about new features.
User | Count |
---|---|
25 | |
10 | |
7 | |
6 | |
6 |
User | Count |
---|---|
30 | |
11 | |
11 | |
10 | |
6 |