Shantanu's Blog

Database Consultant

July 25, 2011

 

Finding errors in the .sql script

You can disable foreign key and run the script to check if mysql throws any errors other than foreign key constraint.

# cat foreign_key.txt
set foreign_key_checks=0;

# cat foreign_key.txt db_name_updates.sql | mysql db_name
_____

When you need to import data, it is better to disable foreign key checks temporarily so that queries do not fail.
mysql> SET foreign_key_checks = 0

The problem with this is that you have to insert the statement at the beginning of every import file. If mysql reconnects automatically, it "forgets" the setting. There is no way to disable it at server level.

mysql> SET GLOBAL init_connect='SET foreign_key_checks = 0';

We can use initial connect feature to disable foregin keys. Any user that does not have "super" privilege will follow this command.
If you are creating users with "grant all on *.* " syntax, then you are out of luck.
I would suggest that a new user can be created for the purpose of executing the scripts those needs to bypass the foreign key checks. The easiest way to create such user is given below:

grant all on *.* to 'reader'@'%' identified by 'reader@123' with grant option;
revoke super on *.* from 'reader'@'%';

You can now use the "reader" user to execute the scripts those needs to by executed at any cost and should bypass foreign-keys.

_____

In order to know the exact queries where mysql found an error, use the following syntax.
# cat db_name_updates.sql | mysql db_name -f -vvv > db_name_updates_success.txt 2> db_name_updates_err.txt

Labels:


 

Managing Auto-incremented ID

Managing the auto_ids can be very difficult while automating the mysql process.
Here is a way to handle it more efficiently.

mysql> insert into country values (NULL, 'Norway');
Query OK, 1 row affected (0.00 sec)

The following statement will save the last auto id to a variable as well as write it to a text file.

mysql> select @myvar:=last_insert_id() into outfile 'country_last_id.txt';

# cat /var/lib/mysql/test/country_last_id.txt
5

Any script can now pick up this auto_incremented value from the text file and use it.

Labels:


July 23, 2011

 

schema and data sync

We are going to learn how update the production data to be in sync with the development server. We will use 3 utilities.

1) diff : This is linux built-in command to compare 2 files.

2) Maatkit: This will be used to compare checksum values of 2 tables and the data differences.
http://www.maatkit.org/doc/

3) schemasync: This utility is used to compare structural differences.
http://schemasync.org/

______________________________________

I) Schema sync

We will first make sure that the table structure of localhost mktest table matches with the SERVER_A table structure.
In the following example, the column "mytime" is missing. How do we know that? How do we create the alter table statement?

server:localhost
schema: test

mysql> select * from mktest;
+----+----------+--------+------+
| id | f_amount | myname | city |
+----+----------+--------+------+
| 1 | NULL | abc | NULL |
| 3 | NULL | abc | NULL |
| 6 | NULL | abc | NULL |
| 8 | NULL | abc | NULL |
| 9 | NULL | abc | NULL |
| 21 | NULL | abc | NULL |
+----+----------+--------+------+
6 rows in set (0.00 sec)


server: SERVER_A
schema: test

mysql> select * from mktest;
+----+----------+--------+------+--------+
| id | f_amount | myname | city | mytime |
+----+----------+--------+------+--------+
| 1 | NULL | abc | NULL | NULL |
| 3 | NULL | abc | NULL | NULL |
| 5 | NULL | abc | NULL | NULL |
| 6 | NULL | abc | NULL | NULL |
| 8 | NULL | abc | NULL | NULL |
| 9 | NULL | abc | NULL | NULL |
| 11 | NULL | abc | NULL | NULL |
+----+----------+--------+------+--------+
7 rows in set (0.00 sec)


# diff <(mysqldump -hSERVER_A -uroot -proot@123 test mktest --skip-extended-insert -d -R) <(mysqldump -hlocalhost -uroot -proot@123 test mktest --skip-extended-insert -d -R) --side-by-side --suppress-common-lines --width=190 | more
-- Host: SERVER_A Database: test | -- Host: localhost Database: test
`mytime` datetime default NULL, <
) ENGINE=MyISAM AUTO_INCREMENT=12 DEFAULT CHARSET=latin1; | ) ENGINE=InnoDB AUTO_INCREMENT=22 DEFAULT CHARSET=latin1;

*** mytime column needs to be added and the table type needs to be changed from InnoDB to MyISAM ***
_____

The diff utility does not generate ready to execute alter statements. We need a third party utility called schemasync.

# schemasync mysql://root:root@123@localhost:3306/test mysql://root:root@123@SERVER_A:3306/test

# cat /home/shantanu/test.20110720.patch.sql
USE `test`;
ALTER TABLE `mktest` ADD COLUMN `mytime` datetime NULL AFTER `city`;

It will also generate an alter table statement to change the table type.

______________________________________

II) Data Sync:

Now that our structure is in order, let's see what records are added / updated.

server:localhost
schema: test

mysql> select * from mktest;
+----+----------+--------+------+--------+
| id | f_amount | myname | city | mytime |
+----+----------+--------+------+--------+
| 1 | NULL | abc | NULL | NULL |
| 3 | NULL | abc | NULL | NULL |
| 6 | NULL | abc | NULL | NULL |
| 8 | NULL | abc | NULL | NULL |
| 9 | NULL | abc | NULL | NULL |
| 21 | NULL | abc | NULL | NULL |
+----+----------+--------+------+--------+
6 rows in set (0.00 sec)

_____

server: SERVER_A
schema: test

mysql> select * from mktest;
+----+----------+--------+------+--------+
| id | f_amount | myname | city | mytime |
+----+----------+--------+------+--------+
| 1 | NULL | abc | NULL | NULL |
| 3 | NULL | abc | NULL | NULL |
| 5 | NULL | abc | NULL | NULL |
| 6 | NULL | abc | NULL | NULL |
| 8 | NULL | abc | NULL | NULL |
| 9 | NULL | abc | NULL | NULL |
| 11 | NULL | abc | NULL | NULL |
+----+----------+--------+------+--------+
7 rows in set (0.00 sec)


a) Checksum match:
We need to find out if the checksum values of these 2 tables match. If the row count and checksum values are the same, the table are exactly the same.

# /usr/bin/mk-table-checksum h=SERVER_A,u=root,p=root@123,P=3306 --databases test --tables mktest h=localhost,u=root,p=root@123,P=3306 --databases test --tables mktest --count | /usr/bin/mk-checksum-filter
test mktest 0 SERVER_A MyISAM 7 4d38da45 0 0 NULL NULL
test mktest 0 localhost MyISAM 6 f1e08b3d 0 0 NULL NULL

There is a difference of 1 row and the checksum value does not match. So we need to find out what are those records.
_____

b) Finding differences:

# diff <(mysqldump -hSERVER_A -uroot -proot@123 test mktest --skip-extended-insert) <(mysqldump -hlocalhost -uroot -proot@123 test mktest --skip-extended-insert) --side-by-side --suppress-common-lines --width=190 | more
-- Host: SERVER_A Database: test | -- Host: localhost Database: test
) ENGINE=MyISAM AUTO_INCREMENT=12 DEFAULT CHARSET=latin1; | ) ENGINE=MyISAM AUTO_INCREMENT=22 DEFAULT CHARSET=latin1;
INSERT INTO `mktest` VALUES (5,NULL,'abc',NULL,NULL); <
INSERT INTO `mktest` VALUES (11,NULL,'abc',NULL,NULL); | INSERT INTO `mktest` VALUES (21,NULL,'abc',NULL,NULL);

The above screen shows that one row is missing from localhost while the another row ID should be 11 instead of 21.
_____

c) Generate SQL:
So we need one insert statement and one update. The maatkit table sync utility has generated delete / insert combo instead of update as shown below:

# /usr/bin/mk-table-sync --print h=SERVER_A,u=root,p=root@123,P=3306 --databases test --tables mktest h=localhost,u=root,p=root@123,P=3306 --databases test --tables mktest
DELETE FROM `test`.`mktest` WHERE `id`='21' LIMIT 1 ;
INSERT INTO `test`.`mktest`(`id`, `f_amount`, `myname`, `city`, `mytime`) VALUES ('5', NULL, 'abc', NULL, NULL) ;
INSERT INTO `test`.`mktest`(`id`, `f_amount`, `myname`, `city`, `mytime`) VALUES ('11', NULL, 'abc', NULL, NULL) ;

Labels: ,


July 14, 2011

 

Remove all except latest 2 files

Let's assume I want to remove all the older backup files from the current directory, except the last 2 latest files. One way of doing this is to move the latest file to another location and then remove all the files starting with data_diff_*

But such a process can not be set in cron nor it can be used in a script.
Here is a linux command that will do this for you. For free!!

# ls -lht
total 169M
-rw-r--r-- 1 root root 1.8M Apr 25 00:55 data_diff_0425.txt.zip
-rw-r--r-- 1 mysql mysql 1.8M Apr 24 00:55 data_diff_0424.txt.zip
-rw-r--r-- 1 mysql mysql 1.8M Apr 23 00:55 data_diff_0423.txt.zip
-rw-r--r-- 1 mysql mysql 1.8M Apr 22 00:55 data_diff_0422.txt.zip
-rw-r--r-- 1 mysql mysql 3.5M Apr 21 00:55 data_diff_0421.txt.zip
-rw-r--r-- 1 mysql mysql 1.8M Apr 20 00:55 data_diff_0420.txt.zip
...

# (ls data_diff_*.txt.zip -t | head -n 2; ls data_diff_*.txt.zip)| sort | uniq -u | xargs rm

# ls -lht
total 3.5M
-rw-r--r-- 1 root root 1.8M Apr 25 00:55 data_diff_0425.txt.zip
-rw-r--r-- 1 mysql mysql 1.8M Apr 24 00:55 data_diff_0424.txt.zip

Labels: ,


Archives

June 2001   July 2001   January 2003   May 2003   September 2003   October 2003   December 2003   January 2004   February 2004   March 2004   April 2004   May 2004   June 2004   July 2004   August 2004   September 2004   October 2004   November 2004   December 2004   January 2005   February 2005   March 2005   April 2005   May 2005   June 2005   July 2005   August 2005   September 2005   October 2005   November 2005   December 2005   January 2006   February 2006   March 2006   April 2006   May 2006   June 2006   July 2006   August 2006   September 2006   October 2006   November 2006   December 2006   January 2007   February 2007   March 2007   April 2007   June 2007   July 2007   August 2007   September 2007   October 2007   November 2007   December 2007   January 2008   February 2008   March 2008   April 2008   July 2008   August 2008   September 2008   October 2008   November 2008   December 2008   January 2009   February 2009   March 2009   April 2009   May 2009   June 2009   July 2009   August 2009   September 2009   October 2009   November 2009   December 2009   January 2010   February 2010   March 2010   April 2010   May 2010   June 2010   July 2010   August 2010   September 2010   October 2010   November 2010   December 2010   January 2011   February 2011   March 2011   April 2011   May 2011   June 2011   July 2011   August 2011   September 2011   October 2011   November 2011   December 2011   January 2012   February 2012   March 2012   April 2012   May 2012   June 2012   July 2012   August 2012   October 2012   November 2012   December 2012   January 2013   February 2013   March 2013   April 2013   May 2013   June 2013   July 2013   September 2013   October 2013   January 2014   March 2014   April 2014   May 2014   July 2014   August 2014   September 2014   October 2014   November 2014   December 2014   January 2015   February 2015   March 2015   April 2015   May 2015   June 2015   July 2015   August 2015   September 2015   January 2016   February 2016   March 2016   April 2016   May 2016   June 2016   July 2016   August 2016   September 2016   October 2016   November 2016   December 2016   January 2017   February 2017   April 2017   May 2017   June 2017   July 2017   August 2017   September 2017   October 2017   November 2017   December 2017   February 2018   March 2018   April 2018   May 2018   June 2018   July 2018   August 2018   September 2018   October 2018   November 2018   December 2018   January 2019   February 2019   March 2019   April 2019   May 2019   July 2019   August 2019   September 2019   October 2019   November 2019   December 2019   January 2020   February 2020   March 2020   April 2020   May 2020   July 2020   August 2020   September 2020   October 2020   December 2020   January 2021   April 2021   May 2021   July 2021   September 2021   March 2022   October 2022   November 2022   March 2023   April 2023   July 2023   September 2023   October 2023   November 2023   April 2024   May 2024   June 2024   August 2024   September 2024   October 2024  

This page is powered by Blogger. Isn't yours?