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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
JosephineUa
Regular Visitor

Lookup a value on another row of the same table

Hi, 

I need to lookup value in a same table, I tried to write query on language M, as I use Power Query in Excel. I know how to write it with an addtitional query and merge it, but I don't know how to do it in same query, as my data has over million lines and if I add another query with million lines it takes a lot of time and PC resources to update it .

I can also use DAX in Power Pivot, but I have an error and don't know how to fix it. 

Test1.jpg

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

1st step: I need to look up user ID2 by colum user ID1 and show user mail

 

I tried =LOOKUPVALUE([User_ID2];[User_ID1];[user_email]), but it shows me an error "Function 'LOOKUPVALUE' does not support comparing values of type Integer with values of type Text. Consider using the VALUE or FORMAT function to convert one of the values."

I tried to fix it with FORMAT formula, but dont understand syntax FORMAT(<value>, <format_string>) and I still have an error, LOOKUPVALUE([User_ID2];[User_ID1]; Format ([user_email], text).

 

2nd step: combine user id2 with 1st step and show (result #1)

3rd step: combine all project names with same user id2 (result #2)

 

I know how to do 2nd and 3rd step in Power Query editor, but i suppose if I'll do 1st step in DAX this column will not be awailable in editor... So probably would need to do all steps in DAX

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

Hi @JosephineUa

1. create a new table

New Table = SUMMARIZE(ALL(Table1),[user id1],Table1[user email])

then edit the relationship between this new table and your data table based on Table1[user id2] to New Table[user id1]

 

2.create calculted columns in the Table1

related = RELATED('Table'[user email])

result1 = IF([user id2]<>BLANK(),CONCATENATE(CONCATENATE([user id2],";"),[related]))

result2 =
CONCATENATEX (
    FILTER (
        SUMMARIZE ( Table1, [user id2], Table1[project name] ),
        [user id2] = EARLIER ( Table1[user id2] )
    ),
    [project name],
    ";"
)

8.png

 

More details see my pbix

 

Best Regards

Maggie

 

 

View solution in original post

1 REPLY 1
v-juanli-msft
Community Support
Community Support

Hi @JosephineUa

1. create a new table

New Table = SUMMARIZE(ALL(Table1),[user id1],Table1[user email])

then edit the relationship between this new table and your data table based on Table1[user id2] to New Table[user id1]

 

2.create calculted columns in the Table1

related = RELATED('Table'[user email])

result1 = IF([user id2]<>BLANK(),CONCATENATE(CONCATENATE([user id2],";"),[related]))

result2 =
CONCATENATEX (
    FILTER (
        SUMMARIZE ( Table1, [user id2], Table1[project name] ),
        [user id2] = EARLIER ( Table1[user id2] )
    ),
    [project name],
    ";"
)

8.png

 

More details see my pbix

 

Best Regards

Maggie

 

 

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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