March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe 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
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
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
23 | |
16 | |
12 | |
9 | |
7 |
User | Count |
---|---|
38 | |
32 | |
25 | |
12 | |
11 |