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

The Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.

Reply
SintRa
Regular Visitor

Lookup values matching more than one columns

 

Hi,

I have the following two tables and I would like to create:

1) A measure or column (not sure what is best) to return the number of companies
2) A calculate table to get records in table 1 which do no exist in table2 matching and returning user and Role columns

 

can you help me? I tried with Vlookup but I am not sure how to return and search using two columns

Sintya_0-1712294148436.png

 

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

Hi, @SintRa 

Maybe you can try the following DAX

First, create a new column:

Column =
VAR _virtualTable =
    FILTER (
        CROSSJOIN (
            SELECTCOLUMNS ( 'Table1', "User1", 'Table1'[User], "Role1", 'Table1'[Role] ),
            SELECTCOLUMNS (
                'Table2',
                "User2", 'Table2'[User],
                "Role2", 'Table2'[Role],
                "Company", 'Table2'[Company]
            )
        ),
        [Role1] = [Role2]
            && [User1] = [User2]
    )
RETURN
    IF (
        COUNTX (
            FILTER ( _virtualTable, 'Table1'[User] = [User1] && 'Table1'[Role] = [Role1] ),
            [Company]
        )
            = BLANK (),
        0,
        COUNTX (
            FILTER ( _virtualTable, 'Table1'[User] = [User1] && 'Table1'[Role] = [Role1] ),
            [Company]
        )
    )

vyohuamsft_0-1712557198765.png

 

Regarding the second question, create a calculated table:

Table1NotInTable2 =
EXCEPT (
    SELECTCOLUMNS ( 'Table1', "User", 'Table1'[User], "Role", 'Table1'[Role] ),
    SELECTCOLUMNS ( 'Table2', "User", 'Table2'[User], "Role", 'Table2'[Role] )
)

vyohuamsft_1-1712557378054.png

 

How to Get Your Question Answered Quickly 

Best Regards

Yongkang Hua

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

3 REPLIES 3
v-yohua-msft
Community Support
Community Support

Hi, @SintRa 

Maybe you can try the following DAX

First, create a new column:

Column =
VAR _virtualTable =
    FILTER (
        CROSSJOIN (
            SELECTCOLUMNS ( 'Table1', "User1", 'Table1'[User], "Role1", 'Table1'[Role] ),
            SELECTCOLUMNS (
                'Table2',
                "User2", 'Table2'[User],
                "Role2", 'Table2'[Role],
                "Company", 'Table2'[Company]
            )
        ),
        [Role1] = [Role2]
            && [User1] = [User2]
    )
RETURN
    IF (
        COUNTX (
            FILTER ( _virtualTable, 'Table1'[User] = [User1] && 'Table1'[Role] = [Role1] ),
            [Company]
        )
            = BLANK (),
        0,
        COUNTX (
            FILTER ( _virtualTable, 'Table1'[User] = [User1] && 'Table1'[Role] = [Role1] ),
            [Company]
        )
    )

vyohuamsft_0-1712557198765.png

 

Regarding the second question, create a calculated table:

Table1NotInTable2 =
EXCEPT (
    SELECTCOLUMNS ( 'Table1', "User", 'Table1'[User], "Role", 'Table1'[Role] ),
    SELECTCOLUMNS ( 'Table2', "User", 'Table2'[User], "Role", 'Table2'[Role] )
)

vyohuamsft_1-1712557378054.png

 

How to Get Your Question Answered Quickly 

Best Regards

Yongkang Hua

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

Thanks @v-yohua-msft, it helps a lot! I could not reach this solution!!!

johnbasha33
Super User
Super User

@SintRa 
Number of Companies = COUNTROWS(DISTINCT('Table 1'[Company]))

Missing Records =
EXCEPT(
'Table 1',
'Table 2'
)

 

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!

FebPBI_Carousel

Power BI Monthly Update - February 2025

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

Feb2025 NL Carousel

Fabric Community Update - February 2025

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