MySQL Forums
Forum List  »  Newbie

Re: Find missing columns
Posted by: Peter Brawley
Date: July 04, 2017 03:56PM

Um, a query not working very seldom indicates a MySQL bug. 99.9%+ of the time, the bug is in the query.

Your query asks for table columns not named 'C1'. What you want, though, are tables that do not have such a column.

Listing data that doesn't exist is more complicated for SQL than listing data that does exist. This is easier to understand if we ask how to find tables that do have a 'C1' column:

select a.table_schema, a.table_name
from information_schema.tables a
join (
  select table_schema, table_name
  from information_schema.columns
  where column_name='C1'
) b using(table_schema, table_name) ;

How do we change that query so it reports tables not having a 'C1' column? Change the Inner Join into an Exclusion Join, ie a Left Join that excludes matches, ie it reports only match failures:

select a.table_schema, a.table_name
from information_schema.tables a
left join (
  select table_schema, table_name
  from information_schema.columns
  where column_name='C1'
) b using(table_schema, table_name)
where b.table_schema is null;   -- include only non-matches

Options: ReplyQuote


Subject
Written By
Posted
July 04, 2017 02:55PM
Re: Find missing columns
July 04, 2017 03:56PM
July 04, 2017 11:55PM
July 05, 2017 09:18AM


Sorry, you can't reply to this topic. It has been closed.

Content reproduced on this site is the property of the respective copyright holders. It is not reviewed in advance by Oracle and does not necessarily represent the opinion of Oracle or any other party.