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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
An0n
Frequent Visitor

Show values in a matrix from two different tables based on a special ID column in each table

I'm trying to show values in a matrix from two different tables based on an ID column in text format. This ID column does not match fully between the two tables and one ID can still have multiple rows attached to it.

 

Table 1

IDColumn 3Column 4Column 5AMOUNT Table 1
AFG137B08xyz1277US4
BFD159B08xyz1233EU15
BFD159B08abc1245DE12
CCC096A22def1233US9
XTU544L51xyz1245EU6

 

Table 2

IDColumn 3Column 4Column 5AMOUNT Table 2
AFG137B08xyz1277US7
BFD159B08xyz1233EU20
CCC096A22abc1245DE3
BVN213H78def1233US14
AFG137B08bte1245US13

 

Desired Matrix in visuals

IDAMOUNT Table 1AMOUNT Table 2Difference AMOUNT Table 1 and Table 2
AFG137B08420-16
BFD159B0827207
CCC096A22936
BVN213H78014-14
XTU544L51606

 

Hope this helps to describe the problem.

 

Thanks in advance!

1 ACCEPTED SOLUTION
v-yiruan-msft
Community Support
Community Support

Hi @An0n ,

I create a sample pbix file(see the attachment), please check if that is what you want. 

1. Create a dimension table with IDs which is from both Table 1 and Table 2

IDs = DISTINCT ( UNION ( VALUES ( 'Table 1'[ID] ), VALUES ( 'Table 2'[ID] ) ) )

yingyinr_0-1675651037717.png

2. Create the measures as below to get the sum of amount in Table 1 and Table 2, the difference of amount

Amount_t1 = 
VAR _selid =
    SELECTEDVALUE ( 'IDs'[ID] )
RETURN
    CALCULATE (
        SUM ( 'Table 1'[AMOUNT Table 1] ),
        FILTER ( 'Table 1', 'Table 1'[ID] = _selid )
    ) + 0
Amount_t2 = 
VAR _selid =
    SELECTEDVALUE ( 'IDs'[ID] )
RETURN
    CALCULATE (
        SUM ( 'Table 2'[AMOUNT Table 2] ),
        FILTER ( 'Table 2', 'Table 2'[ID] = _selid )
    ) + 0
Difference of Amount = [Amount_t1]-[Amount_t2]

3. Create a table visual as below screenshot

yingyinr_1-1675651087062.png

Best Regards

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
v-yiruan-msft
Community Support
Community Support

Hi @An0n ,

I create a sample pbix file(see the attachment), please check if that is what you want. 

1. Create a dimension table with IDs which is from both Table 1 and Table 2

IDs = DISTINCT ( UNION ( VALUES ( 'Table 1'[ID] ), VALUES ( 'Table 2'[ID] ) ) )

yingyinr_0-1675651037717.png

2. Create the measures as below to get the sum of amount in Table 1 and Table 2, the difference of amount

Amount_t1 = 
VAR _selid =
    SELECTEDVALUE ( 'IDs'[ID] )
RETURN
    CALCULATE (
        SUM ( 'Table 1'[AMOUNT Table 1] ),
        FILTER ( 'Table 1', 'Table 1'[ID] = _selid )
    ) + 0
Amount_t2 = 
VAR _selid =
    SELECTEDVALUE ( 'IDs'[ID] )
RETURN
    CALCULATE (
        SUM ( 'Table 2'[AMOUNT Table 2] ),
        FILTER ( 'Table 2', 'Table 2'[ID] = _selid )
    ) + 0
Difference of Amount = [Amount_t1]-[Amount_t2]

3. Create a table visual as below screenshot

yingyinr_1-1675651087062.png

Best Regards

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Thank you @v-yiruan-msft this solution worked for me.

May I have a short follow-up request?

How do I show the correct column totals? They currrently show zero on my end, as also in your example.

 

Appreciate your help, thanks in advance!

Hi @An0n ,

I updated the sample pbix file(see the attachment), please check if that is what you want.

1. Create another two measures as below to replace the measure [Amount_t1] and [Amount_t2] onto the visual

Measure = SUMX(VALUES('IDs'[ID]),[Amount_t1])
Measure 2 = SUMX(VALUES('IDs'[ID]),[Amount_t2])

2. Update the formula of measure [Difference of Amount] as below

Difference of Amount = [Measure]-[Measure 2]

yingyinr_0-1677826177283.png

Best Regards

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
FreemanZ
Super User
Super User

hi @An0n 

one way of implementation is to create sum tables each then you can join them and then calculate. Like:

SumTable1 =
ADDCOLUMNS
    VALUES(Table1[ID],
    "Amount1",
    CALCULATE(SUM(Table1[Amount]))
)

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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