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
Anan2609
New Member

I want craete table chart and show all column from table A but curreency rate get from table B in cu

 TableA

invoice noinvoicedateinvoicevaluecurrency
inv102-01-2022100usd
    

 

Table B

currencyinrrateeffectivefrom
usd7025-12-2021
usd7501-01-2022
usd7805-01-2022
ueuro9802-01-2022

 

I want craete table chart and show all column from table A but curreency rate get from table B in currency column

 

 OUTPUT

invoice noinvoicedateinvoicevaluecurrency
inv102-01-202210075
1 ACCEPTED SOLUTION
v-yingjl
Community Support
Community Support

Hi @Anan2609 ,

You can try this query in TableA:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WyswrM1TSUTIyMDLSN9Q3AjINDQyAZGlxilJsLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"invoice no" = _t, #"invoice date" = _t, #"invoice value" = _t, currency = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"invoice no", type text}, {"invoice date", type date}, {"invoice value", Int64.Type}, {"currency", type text}}),
    #"Merged Queries" = Table.NestedJoin(#"Changed Type", {"currency"}, TableB, {"currency"}, "TableB", JoinKind.LeftOuter),
    #"Added Custom" = 
        Table.AddColumn(
            #"Merged Queries", "Result", each 
                let x = [invoice date] 
                in 
                    Table.Max(Table.SelectRows([TableB], each [effective from] <= x),{"inrrate"})[inrrate]
                , Int64.Type
        ),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"currency", "TableB"})
in
    #"Removed Columns"

vyingjl_0-1646113085854.png

 

Best Regards,
Community Support Team _ Yingjie Li
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

2 REPLIES 2
v-yingjl
Community Support
Community Support

Hi @Anan2609 ,

You can try this query in TableA:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WyswrM1TSUTIyMDLSN9Q3AjINDQyAZGlxilJsLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"invoice no" = _t, #"invoice date" = _t, #"invoice value" = _t, currency = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"invoice no", type text}, {"invoice date", type date}, {"invoice value", Int64.Type}, {"currency", type text}}),
    #"Merged Queries" = Table.NestedJoin(#"Changed Type", {"currency"}, TableB, {"currency"}, "TableB", JoinKind.LeftOuter),
    #"Added Custom" = 
        Table.AddColumn(
            #"Merged Queries", "Result", each 
                let x = [invoice date] 
                in 
                    Table.Max(Table.SelectRows([TableB], each [effective from] <= x),{"inrrate"})[inrrate]
                , Int64.Type
        ),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"currency", "TableB"})
in
    #"Removed Columns"

vyingjl_0-1646113085854.png

 

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

lbendlin
Super User
Super User

You do this with a proper data model including a calendar table. Please provide sanitized sample data that fully covers your issue. If you paste the data into a table in your post (as you already did) or use one of the file services it will be easier to work with. 


Please show the expected outcome based on the sample data you provided. Screenshots of the expected outcome are ok.

https://community.powerbi.com/t5/Desktop/How-to-Get-Your-Question-Answered-Quickly/m-p/1447523

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
Top Kudoed Authors