Active Member
May 16, 2020
I am totally new to Power Query and fascinated by the possibilities!
For the start, I wanted to load information from a number of websites where the same table (with different content of course) is in a different position. The table of interest is either Table 2 or Table 3, depending on the page.
Table 2 gives me the weekly stats here https://manager.kicker.de/clas.....erid/80766
Table 3 gives me the weekly stats here https://manager.kicker.de/clas.....erid/42271
The setup and the headers of the table of interest is the same - is there a way that I can access the correct table from the website by dynamically identifying the start of the right table through the headers for example?
As a newbie, I only got the standard code:
let
Source = Web.Page(Web.Contents("https://manager.kicker.de/classic/bundesliga/spieleranalyse/spielerid/63586")),
Data3 = Source{3}[Data],
#"Changed Type" = Table.TransformColumnTypes(Data3,{{"SpT", Int64.Type}, {"Tore", type text}, {"Elfm.", type text}, {"Ass.", type text}, {"ScP.", type text}, {"R.", type text}, {"GR.", type text}, {"G.", type text}, {"E.", type text}, {"A.", type text}, {"Note", type text}, {"Gegner", type text}, {"", type text}, {"Ergebnis", type text}, {"Bericht", type text}})
in
#"Changed Type"
Power Query
Power Pivot
Xtreme Pivot Tables
Excel for Decision Making
Excel for Finance
Excel Analysis Toolpak
Power BI
Excel
Word
Outlook
Excel Expert
Excel Customer Service
PowerPoint
November 8, 2013
Hi Fabian,
When you start the query from Web, make sure that you click on the left side the folder, not on one of the tables and click on Transform Data.
This should give you a list of all tables from the webpage you are analyzing.
At this point, you have 2 options:
you can add a new column counting the columns of the tables, the one you're after has 15 columns, all others are much smaller. Filter the table to keep only the one you want and expand it (Table.ColumnCount([Data]))
Or, compare the list of headers with the one you need: (also in a new column formula)
Table.ColumnNames([Data])={"SpT","Tore","Elfm.", "Ass.","ScP.","R.", "GR.", "G.", "E.", "A.", "Note","Gegner","","Ergebnis", "Bericht"})
Filter the column to remove False results and expand the Data column.
Active Member
May 16, 2020
Hi Catalin,
that was very helpful, thank you.
I was able to use your advice (just needed to add one more bracket to it), but stumbled across another problem where you might have an idea.
So I am retrieving the data from a series of URLs and as described above, the table of interest is in different positions and your code helped me to identify the correct table. Now on some of the URLs, the table that I am looking for, will not be found because it is not on every on of the URLs on the list. In this case Excel produces an error and aborts the query: "The operation failed because the source database does not exist, the source table does not exist, or because you do not have access to the data source."
Is there a way to "skip on error" if the table cannot be found? My current full query is as below.
Spielerliste is a table containing all URLs that I access to find the table of interest. I am not sure if my problem with the missing table and therefore impossible to fetch the data is best addressed with your step or with the "loop" how to proceed in case of errors. I have been searching online quite a lot, but could not find anything helpful.
Any idea is appreciated 🙂
(Spielerliste) as table =>
let
Source = Web.Page(Web.Contents(Spielerliste)),
#"Added Custom" = Table.AddColumn(Source, "Custom", each Table.ColumnNames([Data])=({"SpT","Tore","Elfm.", "Ass.","ScP.","R.", "GR.", "G.", "E.", "A.", "Note","Gegner","","Ergebnis", "Bericht"})),
#"Filtered Rows" = Table.SelectRows(#"Added Custom", each [Custom] <> false),
Data = #"Filtered Rows"{0}[Data],
#"Changed Type" = Table.TransformColumnTypes(Data,{{"SpT", Int64.Type}, {"Tore", type text}, {"Elfm.", type text}, {"Ass.", type text}, {"ScP.", type text}, {"R.", type text}, {"GR.", type text}, {"G.", type text}, {"E.", type text}, {"A.", type text}, {"Note", type number}, {"Gegner", type text}, {"", type text}, {"Ergebnis", type text}, {"Bericht", type text}})
in
#"Changed Type"
let
Source = Excel.CurrentWorkbook(){[Name="Spielerliste"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Spieler", type text}, {"€", Int64.Type}, {"Verein", type text}, {"#", Int64.Type}, {"Webseite", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "FetchData", each Liste([Webseite])),
#"Expanded FetchData" = Table.ExpandTableColumn(#"Added Custom", "FetchData", {"SpT", "Tore", "Elfm.", "Ass.", "ScP.", "R.", "GR.", "G.", "E.", "A.", "Note", "Gegner", "", "Ergebnis", "Bericht"}, {"SpT", "Tore", "Elfm.", "Ass.", "ScP.", "R.", "GR.", "G.", "E.", "A.", "Note", "Gegner", "Column1", "Ergebnis", "Bericht"}),
#"Removed Columns" = Table.RemoveColumns(#"Expanded FetchData",{"Webseite", "Bericht", "#", "Verein", "€", "Elfm.", "Ass.", "ScP.", "G.", "Gegner", "Column1", "Ergebnis"})
in
#"Removed Columns"
Power Query
Power Pivot
Xtreme Pivot Tables
Excel for Decision Making
Excel for Finance
Excel Analysis Toolpak
Power BI
Excel
Word
Outlook
Excel Expert
Excel Customer Service
PowerPoint
November 8, 2013
Check where the error occurs, and avoid error:
#"Added Custom" = Table.AddColumn(#"Changed Type", "FetchData", each try Liste([Webseite]) otherwise #table({"SpT", "Tore", "Elfm.", "Ass.", "ScP.", "R.", "GR.", "G.", "E.", "A.", "Note", "Gegner", "", "Ergebnis", "Bericht"},{}) ),
We just return an empty table (headers only) if the function fails, to prevent errors on next steps.
1 Guest(s)