cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
Helper I
Helper I

Historical exchange rate API

Hi,

 

I am looking for a way to get historical exchange rates into my report - also daily updated rates - and I have been looking at ecb.europa.eu and their rest API, but find it difficult; 

does anyone know a fairly easy way to fetch these figures? 

Disclaimer; I have no developer skills - solely a business analyst, obviously... 

1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
Frequent Visitor

Re: Historical exchange rate API

@MarcoNeukom I would suggest first creating a table with sequential dates on each row. Then by invoking the function, it will send the dates to the function one by one thus returning the exchange rate info for each day. You can use this example which first generates a list of dates of the past 365 days (this is updated with every refresh) and invokes the function:

 

let
    Source = {Number.From(Date.AddDays(DateTime.Date(DateTime.LocalNow()),-365))..Number.From(DateTime.Date(DateTime.LocalNow()))},
    #"Converted to Table" = Table.FromList(Source, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Changed Type" = Table.TransformColumnTypes(#"Converted to Table",{{"Column1", type date}}),
    #"Renamed Columns" = Table.RenameColumns(#"Changed Type",{{"Column1", "Date"}}),
    #"Invoked Custom Function" = Table.AddColumn(#"Renamed Columns", "ExchangeRates", each Fn_GetHistoricExchangeRates(Date.ToText([Date],"yyyy-MM-dd"))),
    #"Expanded ExchangeRates" = Table.ExpandTableColumn(#"Invoked Custom Function", "ExchangeRates", {"Currency", "Rate"}, {"Currency", "Rate"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Expanded ExchangeRates",{{"Rate", type number}, {"Currency", type text}})
in
    #"Changed Type1"

In order for it to work you should create a function named Fn_GetHistoricExchangeRates, by using the code in my previous post.

 

Hope that helps!


Jan

View solution in original post

6 REPLIES 6
Highlighted
Solution Sage
Solution Sage

Re: Historical exchange rate API

Hi @MarcoNeukom ,

I will use data from this website: https://www.x-rates.com/historical/?from=USD&amount=1&date=2019-07-17, we can change the url to specified date to get historical exchange rates. Then we can use the web connector in PowerBI to get the data from them:
PBIDesktop_cEiyWMRHcJ.png

Best Regards,

Teige

Highlighted
Helper I
Helper I

Re: Historical exchange rate API

Hi @TeigeGao,

 

Thx for your reply.

I should've been more specific:

 

What I am trying to achieve is to have a line chart with historical rates that refreshes with new datapoints every day. 

ECB has a syntax to do that, but I can't seem to get it to work.

https://sdw-wsrest.ecb.europa.eu/help/ 

 

Highlighted
Frequent Visitor

Re: Historical exchange rate API

@MarcoNeukom I have recently created a simple function that extracts exchange rate information from the site https://exchangeratesapi.io/ which gets its data from the ECB site:

let
    Source = (Date as text) => let
        Source = Json.Document(Web.Contents("https://api.exchangeratesapi.io/" & Date & "?base=USD")),
        rates = Source[rates],
        #"Converted to Table" = Record.ToTable(rates),
        #"Renamed Columns" = Table.RenameColumns(#"Converted to Table",{{"Name", "Currency"}, {"Value", "Rate"}})
    in
        #"Renamed Columns"
in
    Source

Using a datetable or generated range of dates, you can then invoke the custom function like this:

= Table.AddColumn(#"Removed Other Columns", "Rates", each Fn_GetHistoricCurrencyRates(DateTime.ToText([Date],"yyyy-MM-dd")))

Hope that helps!

 

Jan

Highlighted
Helper I
Helper I

Re: Historical exchange rate API

@janvanwerkhoven this looks promising, I stumbled upon that site as well.

I am totally inexperienced with this; "invoke function" lets me enter parameter as date - should I fill in a range of dates and then use the second function you mention? 

Highlighted
Helper I
Helper I

Re: Historical exchange rate API

So you update the URL everytime you want new data? 

Should be possible to get the latest data added to your previous queries and cached responses. 

Highlighted
Frequent Visitor

Re: Historical exchange rate API

@MarcoNeukom I would suggest first creating a table with sequential dates on each row. Then by invoking the function, it will send the dates to the function one by one thus returning the exchange rate info for each day. You can use this example which first generates a list of dates of the past 365 days (this is updated with every refresh) and invokes the function:

 

let
    Source = {Number.From(Date.AddDays(DateTime.Date(DateTime.LocalNow()),-365))..Number.From(DateTime.Date(DateTime.LocalNow()))},
    #"Converted to Table" = Table.FromList(Source, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Changed Type" = Table.TransformColumnTypes(#"Converted to Table",{{"Column1", type date}}),
    #"Renamed Columns" = Table.RenameColumns(#"Changed Type",{{"Column1", "Date"}}),
    #"Invoked Custom Function" = Table.AddColumn(#"Renamed Columns", "ExchangeRates", each Fn_GetHistoricExchangeRates(Date.ToText([Date],"yyyy-MM-dd"))),
    #"Expanded ExchangeRates" = Table.ExpandTableColumn(#"Invoked Custom Function", "ExchangeRates", {"Currency", "Rate"}, {"Currency", "Rate"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Expanded ExchangeRates",{{"Rate", type number}, {"Currency", type text}})
in
    #"Changed Type1"

In order for it to work you should create a function named Fn_GetHistoricExchangeRates, by using the code in my previous post.

 

Hope that helps!


Jan

View solution in original post

Helpful resources

Announcements
June 2020 Community Highlights

June 2020 Community Highlights

Featured community members, changes to the Community, and more! Read up on recent Power BI community news.

Using the Community

Using the Community

Need help with the Power BI Community? Our 'Using the Community' support articles are a great place to start.

Community Summit North America

Community Summit North America

Innovate, Collaborate, Grow. The top training and networking event across the globe for Microsoft Business Applications

Power Platform 2020 release wave 2 plan

Power Platform 2020 release wave 2 plan

Features releasing from October 2020 through March 2021

Top Solution Authors
Top Kudoed Authors