• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
    • Password Reset
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

Websites with the same table in different positions |Power Query|Excel Forum|My Online Training Hub

You are here: Home / Websites with the same table in different positions |Power Query|Excel Forum|My Online Training Hub
Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search|Last Search Results
Search
Forum Scope




Match



Forum Options



Minimum search word length is 3 characters - maximum search word length is 84 characters
sp_Search Search
sp_RankInfo
Lost password?
sp_CrumbsHome HomeExcel ForumPower QueryWebsites with the same table in dif…
sp_PrintTopic sp_TopicIcon
Websites with the same table in different positions
Avatar
Fabian Hupe

Active Member
Members
Level 0
Forum Posts: 3
Member Since:
May 16, 2020
sp_UserOfflineSmall Offline
1
May 16, 2020 - 10:33 am
sp_Permalink sp_Print

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"

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1807
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
2
May 18, 2020 - 1:05 pm
sp_Permalink sp_Print

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.

all.jpgImage Enlarger

sp_PlupAttachments Attachments
  • sp_PlupImage all.jpg (32 KB)
Avatar
Fabian Hupe

Active Member
Members
Level 0
Forum Posts: 3
Member Since:
May 16, 2020
sp_UserOfflineSmall Offline
3
June 6, 2020 - 11:10 am
sp_Permalink sp_Print

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"

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1807
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
4
June 6, 2020 - 1:40 pm
sp_Permalink sp_Print

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.

Avatar
Fabian Hupe

Active Member
Members
Level 0
Forum Posts: 3
Member Since:
May 16, 2020
sp_UserOfflineSmall Offline
5
June 6, 2020 - 10:51 pm
sp_Permalink sp_Print

Now that was easy, thanks so much! 

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Philip Treacy, Ngoc Tinh, Riny van Eekelen
Guest(s) 11
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 870
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
A.Maurizio: 202
Jessica Stewart: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
michael serna
mashal sana
Tiffany Kang
Leah Gillmore
Sopi Yuniarti
LAFONSO HERNANDEZ
Hayden Hao
Angela chen
Sean Moore
John Chisholm
Forum Stats:
Groups: 3
Forums: 24
Topics: 6215
Posts: 27248

 

Member Stats:
Guest Posters: 49
Members: 31897
Moderators: 3
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: MOTH Support, Velouria, Riny van Eekelen
© Simple:Press —sp_Information

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook
 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

Support

  • Contact
  • Forum
  • Helpdesk - For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.