Skip to main content

MySQL: Deleting with Left Join

Today I had to deal with one huge table and cleanup all data where foreign key doesn’t have it’s primary key match in original table, just to remind myself how sub-queries in MySQL are terrible slower than joins.

I have some script which generates domains from typos, so I have one table with original domains (master_domains) and other one (result_domains) with generated typo domains. Basically something like this:

mysql> describe master_domains;
+--------+------------------+------+-----+---------+----------------+
| Field  | Type             | Null | Key | Default | Extra          |
+--------+------------------+------+-----+---------+----------------+
| id     | int(10) unsigned | NO   | PRI | NULL    | auto_increment | 
| domain | varchar(255)     | NO   | UNI | NULL    |                | 
+--------+------------------+------+-----+---------+----------------+
2 rows in set (0.07 sec)

mysql> describe result_domains;
+-----------+------------------+------+-----+---------+----------------+
| Field     | Type             | Null | Key | Default | Extra          |
+-----------+------------------+------+-----+---------+----------------+
| id        | int(10) unsigned | NO   | PRI | NULL    | auto_increment | 
| domain    | varchar(255)     | NO   | UNI | NULL    |                | 
| master_id | int(10) unsigned | YES  | MUL | NULL    |                | 
+-----------+------------------+------+-----+---------+----------------+
3 rows in set (0.01 sec)

Table result_domains has master_id which is foreign key reference to primary key (id) in master_domains table. Since I also have other scripts generating domains without typos (which store result_domains.master_id field as NULL), today I simple wanted to get rid of those masters without proper master_id reference in result table or in other words those master domains where result_domains.master_id is NOT NULL.

With sub-queries you could write query easily with something like this:

delete from master_domains where id not in 
(select master_id from result_domains_frontend)

It is good habit to always run select query before deleting big number of rows (just to make sure your query is written correctly) so I tried select query first:

select * from master_domains where id not in 
(select master_id from result_domains_frontend) limit 10

However, it took several minutes to run without any output so eventually I’ve decided to stop it. I know that sub-queries are much slower than joins, so decided to do try removal operation with left join.

Left joins are actually perfect weapon to find rows that exist in one (left) and doesn’t exist in other (right) table. They also have one big advantage over sub-queries – they are performing much faster, plus they are backward compatible with old prehistoric MySQL 5.x versions. However delete syntax is little bit tricky so after few trial and errors eventually I came out with this query:

delete master_domains.* from master_domains 
left join result_domains_frontend 
on master_domains.id=result_domains_frontend.master_id 
where result_domains_frontend.master_id is null ;

And voila after a while it came up with result:

mysql> delete master_domains.* from master_domains 
left join result_domains_frontend 
on master_domains.id=result_domains_frontend.master_id 
where result_domains_frontend.master_id is null ;
Query OK, 270558 rows affected (46.58 sec)
mysql> 

MySQL: Moving table from one db to another

To move one table from one db to another, you can create new table (create table foo_new like foo) in db where you want to move table and then copy data with insert into/select query. However there is much easier way which is especially handy when you deal with big tables.

As you probably aready know, there is easy way to rename MySQL table just by issuing rename clause in alter statement:

ALTER TABLE foo RENAME TO new_foo;

You can also use RENAME TABLE syntax like this:

RENAME TABLE foo TO new_foo;

Now, when you need to move table from one db to another, all you have to do is to specify it’s current db and new db name as table prefix. For example if you want to move table foo from current db to new db you can issue queries like these:

ALTER TABLE currentdb.foo RENAME TO newdb.foo;

or

RENAME TABLE currentdb.foo TO newdb.foo;

Btw there is important difference between ALTER and RENAME statements in a way that with RENAME you can rename more than one tables at once. This comes handy if you want for example to swap names of two tables:

RENAME TABLE table1 TO temp, table2 TO table1, temp TO table2;