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
Anonymous
Not applicable

Lookup table with matching value

I have a dataset with 3 tables .  2 Master table with Unique records and one user table

VM Name
VM  1
VM 2
VM 3
VM 4

 

Sofware Names
Software 1
Software 2
Software 3
Software 4

 

Uswer Table 
VM NameSoftware Installed
VM 1Software 2
VM 2Software 1
VM 3Software 1
VM 3Software 2
VM 3

Software 3

 

Can we identify and add new columns indication which VM is missing which Software and add it in table as records in table for ploting the visuals. tried with lookup but could no succeed . Please assist . 

 

3 ACCEPTED SOLUTIONS

@Anonymous - Probably. See attached PBIX below sig, Tables (29), (29a), (29b), (29c). 29c is the output.

Table (29c) = 
    ADDCOLUMNS(
        GENERATE('Table (29)','Table (29a)'),
        "Owner",LOOKUPVALUE('Table (29b)'[Ower],[VM Name.1],[VM Name],"NA"),
        "Email",LOOKUPVALUE('Table (29b)'[Email],[VM Name.1],[VM Name],"NA"),
        "Subscription ID",LOOKUPVALUE('Table (29b)'[Subscription ID],[VM Name.1],[VM Name],"NA"),
        "Status",IF(COUNTROWS(FILTER('Table (29b)',[VM Name.1]=[VM Name]&&[Software Installed]=[Software Names]))>0,"Installed","Missing")
    )

 Turned out to be a lot of LOOKUPVALUE after all.


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

Anonymous
Not applicable

@Greg_Deckler Thanks .It worked 🙂 

 

 

Can we also do this in same table (29B) instead of a new table creation . 

View solution in original post

@Anonymous - I do not believe so. If you want a full inventory you have to kind of "blowout" the table into more rows than you have in any of the base tables.


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

12 REPLIES 12
amitchandak
Super User
Super User

@Anonymous , this will give you a new table

 

except(crossjoin(all(Table1[VM Name]), selectcolumns(Table2,"Software Installed",Table2[Sofware Names])),Table3)

 

for except you need same name across tables

Greg_Deckler
Super User
Super User

@Anonymous - Not entirely sure of the ask here, LOOKUPVALUE maybe?


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...
Fowmy
Super User
Super User

@Anonymous 

Create a New Table using the code below, which will include all combinations

New Table = 
   CROSSJOIN(
        vm,Software
    )

Add the following Column to it to identify missing combination:

Missing = 
IF( ISEMPTY(
    FILTER(
        user,
        User[VM Name]=EARLIER('New Table'[VM Name]) && User[Software Installed] = EARLIER('New Table'[Sofware Names])
    )
    ),
"MISSING")

 

Fowmy_0-1599141789180.png

________________________

If my answer was helpful, please consider Accept it as the solution to help the other members find it

Click on the Thumbs-Up icon if you like this reply 🙂

YouTube  LinkedIn

 


 

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

Anonymous
Not applicable

@Fowmy  It Helps .. Can I also pick more columns from User table based on VM name in the new table created  ?. 

 

User table has User details for each VM . This would help in plotting the data

@Anonymous 

Yes sure,

The 1st code will work without any change.

You can modify the 2nd code which adds the column. You can add more fileds starting with && as I did for Software Installed in the following

Missing = 
IF( ISEMPTY(
    FILTER(
        user,
        User[VM Name]=EARLIER('New Table'[VM Name]) 
        &&  User[Software Installed] = EARLIER('New Table'[Sofware Names])
    )
    ),
"MISSING")

 
Let me know if you face any issue

________________________

If my answer was helpful, please consider Accept it as the solution to help the other members find it

Click on the Thumbs-Up icon if you like this reply 🙂

YouTube  LinkedIn

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

Anonymous
Not applicable

@Fowmy  I tried but that is not adding a new column as there is a Many to Many cardinality setup .

 

VN name can be duplicate in both the tables . 

 

For Eg  User table has additional columns like  User name, Email ID , Company timestamp etc . I want to add these fields in New table created for ploting the visuals  Or is there any other method to use these directly in visuals.

Graphs like for list of VMs these software are missing and Owner details  .

 

@Anonymous 

Can you share some sample data and the expected result to have a clear understanding of your question?
You can save your files in OneDrive, Google Drive, or any other cloud sharing platforms and share the link here.
____________________________________
How to paste sample data with your question?
How to get your questions answered quickly?

_____________________________________
Did I answer your question? Mark this post as a solution, this will help others!.

Click on the Thumbs-Up icon if you like this reply 🙂

YouTube, LinkedIn

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

Anonymous
Not applicable

@Fowmy  Sharind the sample data as the compelte data set is big with many fields

 

I want to plot the visuals on how many VMs are missing which softwares  .Also some other graphs on subscriptin ID and other criterias based on data set .

 

1. Distinct VM is coming from a different table as that has the complete inventory of the VMs as there could be some VM missing in User table as well ideally which have no Software installed at all. 

2. Distinct softwares I am taking from the user Table itself for finding all permutation and combinations . (as User table only shows the Installed sotware not the missing ones)

3. We can create a new table as well like the output table or if the details can be added on the user tabel itself that would also work as it will help in plotting other graphs.

 

Please suggest on how can I achieve this , tried with many ways however unfortunately couldnot succeed

Distinct VM TableDistinct Software Table User Table
VM NameSofware Names VM NameSoftware InstalledOwerEmailSubscription ID
VM  1Software 1 VM 1Software 2aa@xyz.comx
VM 2Software 2 VM 2Software 1bb@xyz.comy
VM 3Software 3 VM 3Software 1cc@xyz.comz
VM 4Software 4 VM 3Software 2cc@xyz.comz
   VM 3Software 3cc@xyz.comz

 

Desired Output

VM NameSofware NamesOwnerEmailSubscription IDStatus
VM 1Software 1aa@xyz.comxMissing
VM 1Software 2aa@xyz.comxInstalled
VM 1Software 3aa@xyz.comxMissing
VM 1Software 4aa@xyz.comxMissing
VM 2Software 1bb@xyz.comyInstalled
VM 2Software 2bb@xyz.comyMissing
VM 2Software 3bb@xyz.comyMissing
VM 2Software 4bb@xyz.comyMissing
VM 3Software 1cc@xyz.comzInstalled
VM 3Software 2cc@xyz.comzInstalled
VM 3Software 3cc@xyz.comzInstalled
VM 3Software 4cc@xyz.comzMissing
VM 4Software 1NANANAMissing
VM 4Software 2NANANAMissing
VM 4Software 3NANANAMissing
VM 4Software 4NANANAMissing

 

@Greg_Deckler @amitchandak 

Anonymous
Not applicable

@Fowmy @Greg_Deckler  any help here please . Can this be achieved 

@Anonymous - Probably. See attached PBIX below sig, Tables (29), (29a), (29b), (29c). 29c is the output.

Table (29c) = 
    ADDCOLUMNS(
        GENERATE('Table (29)','Table (29a)'),
        "Owner",LOOKUPVALUE('Table (29b)'[Ower],[VM Name.1],[VM Name],"NA"),
        "Email",LOOKUPVALUE('Table (29b)'[Email],[VM Name.1],[VM Name],"NA"),
        "Subscription ID",LOOKUPVALUE('Table (29b)'[Subscription ID],[VM Name.1],[VM Name],"NA"),
        "Status",IF(COUNTROWS(FILTER('Table (29b)',[VM Name.1]=[VM Name]&&[Software Installed]=[Software Names]))>0,"Installed","Missing")
    )

 Turned out to be a lot of LOOKUPVALUE after all.


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...
Anonymous
Not applicable

@Greg_Deckler Thanks .It worked 🙂 

 

 

Can we also do this in same table (29B) instead of a new table creation . 

@Anonymous - I do not believe so. If you want a full inventory you have to kind of "blowout" the table into more rows than you have in any of the base tables.


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

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.

Top Solution Authors