Shantanu's Blog

Database Consultant

January 28, 2011

 

Updatable views

You can use the "with check option" property of view to create constraint that will do the needful of checking the data.
For e.g. if I want to allow the ID 1 into the table parent, I can use "enum" datatype or create a view with appropriate where clause.

drop table child;
drop table parent;

CREATE TABLE parent(
`ID` int(11) default NULL,
`name` varchar(100) default NULL,
`city` varchar(100) default NULL,
primary key (name)
) ENGINE=InnoDB;

create table child(
username varchar(100) not null,
FOREIGN KEY (username) REFERENCES parent(name) on update cascade,
primary key (username)
) ENGINE=InnoDB;

insert into parent values (1, 'abc', 'delhi');
insert into child values ('abc');

create or replace view myview as select * from parent where ID > 0 and ID < 2 with check option;

mysql>insert into myview values (3, 'qqabc', 'wwdelhi');
ERROR 1369 (HY000): CHECK OPTION failed 'test.myview'

mysql>insert into myview values (1, 'qqabc', 'wwdelhi');
Query OK, 1 row affected (0.02 sec)

Labels:


January 18, 2011

 

MySQL Case Study - 182

Finding rows those are NOT 10 digits long

I need to find the rows those are not 10 digits in length and must include a digit and not a alphabet.

CREATE TABLE mobile (mno varchar(100) default NULL);
INSERT INTO mobile VALUES ('223456780'),('2234567890'),('4234567890'),('6234567890'),('22345678aaaa0'),('123456789a');

mysql> select * from mobile;
+---------------+
| mno |
+---------------+
| 223456780 |
| 2234567890 |
| 4234567890 |
| 6234567890 |
| 22345678aaaa0 |
| 123456789a |
+---------------+
6 rows in set (0.00 sec)

mysql> select * from mobile WHERE length(mno) != 10;
+---------------+
| mno |
+---------------+
| 223456780 |
| 22345678aaaa0 |
+---------------+
2 rows in set (0.00 sec)

mysql> select * from mobile WHERE mno NOT RLIKE '[0-9]{10}';
+---------------+
| mno |
+---------------+
| 223456780 |
| 22345678aaaa0 |
| 123456789a |
+---------------+
3 rows in set (0.00 sec)

Labels:


January 12, 2011

 

One more way to select

I can write the following query if I know the exact column name where I expect to find the matching value.
select * from parent where city = 'Delhi'
But it is interesting to know that grep can be used at the command prompt that will return only the records where that appear.

mysql>pager grep Delhi
PAGER set to 'grep Delhi'

mysql>select * from parent;
| 2 | Amar | Delhi |
| 5 | Akbar | Delhi |
| 8 | Anthony | Delhi |
10 rows in set (0.00 sec)

mysql>pager
Default pager wasn't set, using stdout.

Labels:


January 06, 2011

 

Top N records per group

Selecting top N records per group is not as easy as it seems. The query may get as complex as you want.

http://code.openark.org/blog/mysql/sql-selecting-top-n-records-per-group

Here is how I would solve it by taking help of composite index with one of the column being auto_id.
InnoDB table types do not support such indexes though.

drop table if exists Country_sort;

CREATE TABLE `Country_sort` (
id int not null auto_increment,
`Code` char(3) NOT NULL default '',
`Name` char(52) NOT NULL default '',
`Continent` enum('Asia','Europe','North America','Africa','Oceania','Antarctica','South America') NOT NULL default 'Asia',
`Region` char(26) NOT NULL default '',
`SurfaceArea` float(10,2) NOT NULL default '0.00',
`IndepYear` smallint(6) default NULL,
`Population` int(11) NOT NULL default '0',
`LifeExpectancy` float(3,1) default NULL,
`GNP` float(10,2) default NULL,
`GNPOld` float(10,2) default NULL,
`LocalName` char(45) NOT NULL default '',
`GovernmentForm` char(45) NOT NULL default '',
`HeadOfState` char(60) default NULL,
`Capital` int(11) default NULL,
`Code2` char(2) NOT NULL default '',
PRIMARY KEY (Continent, id)
) ENGINE=MyISAM;

insert into Country_sort select NULL, Code, Name, Continent, Region, SurfaceArea, IndepYear, Population, LifeExpectancy, GNP, GNPOld, LocalName, GovernmentForm, HeadOfState, Capital, Code2 from Country order by Continent, SurfaceArea desc;

select Continent, name from Country_sort where ID = 1 order by Continent;

select Continent, name, SurfaceArea, Population from Country_sort where ID <= 5 order by Continent, SurfaceArea desc;

Labels:


January 05, 2011

 

Binary collation and text comparison

MySQL by default, ignores capital and small letters in the data:

mysql> create table todel (description varchar(100) COLLATE utf8_bin);
Query OK, 0 rows affected (0.02 sec)

mysql> insert into todel (description) values ('This is MIXED case');
Query OK, 1 row affected (0.00 sec)

mysql> select * from todel where description like '%MIXED%';
+--------------------+
| description |
+--------------------+
| This is MIXED case |
+--------------------+
1 row in set (0.00 sec)

mysql> select * from todel where description like '%mixed%';
+--------------------+
| description |
+--------------------+
| This is MIXED case |
+--------------------+
1 row in set (0.00 sec)

_____

If you want mysql to consider the case, you have to use the "binary" keyword as shown below. The comparison is now case sensitive.

mysql> select * from todel where binary description like '%mixed%';
Empty set (0.00 sec)

mysql> select * from todel where binary description like '%MIXED%';
+--------------------+
| description |
+--------------------+
| This is MIXED case |
+--------------------+
1 row in set (0.00 sec)

_____

If you want all the queries on that column (for e.g. description) to be case sensitive, change the collation to binary in the create table statement.

mysql> create table todel (description varchar(100) COLLATE utf8_bin);
Query OK, 0 rows affected (0.04 sec)

mysql> insert into todel (description) values ('This is MIXED case');
Query OK, 1 row affected (0.00 sec)

mysql> select * from todel where description like '%mixed%';
Empty set (0.00 sec)

mysql> select * from todel where description like '%MIXED%';
+--------------------+
| description |
+--------------------+
| This is MIXED case |
+--------------------+
1 row in set (0.00 sec)

_____

It is recommended NOT to use the utf8_bin collation type for any column. If your table already has one, get rid of it using "alter table modify" statement.

mysql> show create table todel\G
*************************** 1. row ***************************
Table: todel
Create Table: CREATE TABLE `todel` (
`description` varchar(100) character set utf8 collate utf8_bin default NULL
) ENGINE=MyISAM DEFAULT CHARSET=latin1

mysql> alter table todel modify description varchar(100);

mysql> show create table todel\G
*************************** 1. row ***************************
Table: todel
Create Table: CREATE TABLE `todel` (
`description` varchar(100) default NULL
) ENGINE=MyISAM DEFAULT CHARSET=latin1

mysql> alter table todel modify description varchar(100) collate utf8_bin;

mysql> show create table todel\G
*************************** 1. row ***************************
Table: todel
Create Table: CREATE TABLE `todel` (
`description` varchar(100) character set utf8 collate utf8_bin default NULL
) ENGINE=MyISAM DEFAULT CHARSET=latin1

Labels:


January 03, 2011

 

Savepoints in transaction

rollbacks usually let you go back to the start of the transaction, but not necessarily if you use savepoints.
mysql> rollback;

will undo all the statements till the beginning of the transaction, whereas
mysql> rollback to savepoint savepoint_one;

Will revert back to the saved position in the transaction.
You can run the following script to see how savepoints work in transactions/ Stored procedures.


drop table if exists test.savepoint_test;
drop procedure if exists second_fail;
drop procedure if exists prc_work;
CREATE TABLE test.savepoint_test (
id int not null default '0',
name varchar(100),
primary key (id)
)engine=InnoDB;
insert into test.savepoint_test values ('1', 'jack');
insert into test.savepoint_test values ('2', 'akbar');
select * from test.savepoint_test;

start transaction;
update test.savepoint_test set name = 'amar' where id = 1;
select * from savepoint_test;

savepoint savepoint_one;
update savepoint_test set name = 'jill' where id = 2;

select * from savepoint_test;
rollback to savepoint_one;

select * from savepoint_test;

commit;

select 'using savepoints in stored procedures' as message;

delimiter $$
drop procedure if exists second_fail$$
CREATE PROCEDURE second_fail()
BEGIN
INSERT into test.savepoint_test values ('3', 'anthony');
INSERT into test.savepoint_test values ('2', 'xyz');
END;
$$

select 'ID 3 manages to get into the table but ID 2 fails due to duplicate primary key error' as message $$
drop procedure if exists prc_work$$
CREATE PROCEDURE prc_work()
BEGIN
SAVEPOINT sp_prc_work;
BEGIN
DECLARE EXIT HANDLER FOR SQLEXCEPTION ROLLBACK TO sp_prc_work;
INSERT into test.savepoint_test values ('4', 'krishna');
INSERT into test.savepoint_test values ('2', 'abc');
END;
END;
$$

select 'ID 4 qualifies to be inserted but fails because ID 2 fails and the entire transaction is reverted to the savepoint' as message $$

delimiter ;

start transaction;
call second_fail();
select * from test.savepoint_test;

call prc_work();
select * from test.savepoint_test;
commit;

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  

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