創(chuàng)建游標
首先在MySql中創(chuàng)建一張數(shù)據(jù)表:
CREATE TABLE IF NOT EXISTS store
(
id
int(11) NOT NULL AUTO_INCREMENT,
name
varchar(20) NOT NULL,
count
int(11) NOT NULL DEFAULT '1',
PRIMARY KEY (id
)
) ENGINE=InnoDB DEFAULT CHARSET=latin1 AUTO_INCREMENT=7;
INSERT INTO store
(id
, name
, count
) VALUES
(1, 'android', 15),
(2, 'iphone', 14),
(3, 'iphone', 20),
(4, 'android', 5),
(5, 'android', 13),
(6, 'iphone', 13);
我們現(xiàn)在要用存儲過程做一個功能,統(tǒng)計iphone的總庫存是多少知允,并把總數(shù)輸出到控制臺迫横。
--在windows系統(tǒng)中寫存儲過程時茉稠,如果需要使用declare聲明變量,需要添加這個關鍵字谓晌,否則會報錯吸重。
delimiter //
drop procedure if exists StatisticStore;
CREATE PROCEDURE StatisticStore()
BEGIN
--創(chuàng)建接收游標數(shù)據(jù)的變量
declare c int;
declare n varchar(20);
--創(chuàng)建總數(shù)變量
declare total int default 0;
--創(chuàng)建結束標志變量
declare done int default false;
--創(chuàng)建游標
declare cur cursor for select name,count from store where name = 'iphone';
--指定游標循環(huán)結束時的返回值
declare continue HANDLER for not found set done = true;
--設置初始值
set total = 0;
--打開游標
open cur;
--開始循環(huán)游標里的數(shù)據(jù)
read_loop:loop
--根據(jù)游標當前指向的一條數(shù)據(jù)
fetch cur into n,c;
--判斷游標的循環(huán)是否結束
if done then
leave read_loop; --跳出游標循環(huán)
end if;
--獲取一條數(shù)據(jù)時,將count值進行累加操作血巍,這里可以做任意你想做的操作,
set total = total + c;
--結束游標循環(huán)
end loop;
--關閉游標
close cur;
--輸出結果
select total;
END;
--調(diào)用存儲過程
call StatisticStore();
fetch是獲取游標當前指向的數(shù)據(jù)行珊随,并將指針指向下一行述寡,當游標已經(jīng)指向最后一行時繼續(xù)執(zhí)行會造成游標溢出。使用loop循環(huán)游標時叶洞,他本身是不會監(jiān)控是否到最后一條數(shù)據(jù)了鲫凶,像下面代碼這種寫法,就會造成死循環(huán)衩辟;
read_loop:loop
fetch cur into n,c;
set total = total+c;
end loop;
在MySql中螟炫,造成游標溢出時會引發(fā)mysql預定義的NOT FOUND錯誤,所以在上面使用下面的代碼指定了當引發(fā)not found錯誤時定義一個continue 的事件艺晴,指定這個事件發(fā)生時修改done變量的值昼钻。
declare continue HANDLER for not found set done = true;
所以在循環(huán)時加上了下面這句代碼:
--判斷游標的循環(huán)是否結束
if done then
leave read_loop; --跳出游標循環(huán)
end if;
如果done的值是true,就結束循環(huán)封寞。繼續(xù)執(zhí)行下面的代碼然评。
使用方式
游標有三種使用方式:第一種就是上面的實現(xiàn),使用loop循環(huán)狈究;第二種方式如下碗淌,使用while循環(huán):
drop procedure if exists StatisticStore1;
CREATE PROCEDURE StatisticStore1()
BEGIN
declare c int;
declare n varchar(20);
declare total int default 0;
declare done int default false;
declare cur cursor for select name,count from store where name = 'iphone';
declare continue HANDLER for not found set done = true;
set total = 0;
open cur;
fetch cur into n,c;
while(not done) do
set total = total + c;
fetch cur into n,c;
end while;
close cur;
select total;
END;
call StatisticStore1();
第三種方式是使用repeat執(zhí)行:
drop procedure if exists StatisticStore2;
CREATE PROCEDURE StatisticStore2()
BEGIN
declare c int;
declare n varchar(20);
declare total int default 0;
declare done int default false;
declare cur cursor for select name,count from store where name = 'iphone';
declare continue HANDLER for not found set done = true;
set total = 0;
open cur;
repeat
fetch cur into n,c;
if not done then
set total = total + c;
end if;
until done end repeat;
close cur;
select total;
END;
call StatisticStore2();
游標嵌套
在mysql中,每個begin end 塊都是一個獨立的scope區(qū)域,由于MySql中同一個error的事件只能定義一次贯莺,如果多定義的話在編譯時會提示Duplicate handler declared in the same block。
drop procedure if exists StatisticStore3;
CREATE PROCEDURE StatisticStore3()
BEGIN
declare _n varchar(20);
declare done int default false;
declare cur cursor for select name from store group by name;
declare continue HANDLER for not found set done = true;
open cur;
read_loop:loop
fetch cur into _n;
if done then
leave read_loop;
end if;
begin
declare c int;
declare n varchar(20);
declare total int default 0;
declare done int default false;
declare cur cursor for select name,count from store where name = 'iphone';
declare continue HANDLER for not found set done = true;
set total = 0;
open cur;
iphone_loop:loop
fetch cur into n,c;
if done then
leave iphone_loop;
end if;
set total = total + c;
end loop;
close cur;
select _n,n,total;
end;
begin
declare c int;
declare n varchar(20);
declare total int default 0;
declare done int default false;
declare cur cursor for select name,count from store where name = 'android';
declare continue HANDLER for not found set done = true;
set total = 0;
open cur;
android_loop:loop
fetch cur into n,c;
if done then
leave android_loop;
end if;
set total = total + c;
end loop;
close cur;
select _n,n,total;
end;
begin
end;
end loop;
close cur;
END;
call StatisticStore3();
上面就是實現(xiàn)一個嵌套循環(huán)宁改,當然這個例子比較牽強缕探。湊合看看就行。还蹲。
動態(tài)SQL
Mysql 支持動態(tài)SQL的功能爹耗,
set @sqlStr='select * from table where condition1 = ?';
prepare s1 for @sqlStr;
--如果有多個參數(shù)用逗號分隔
execute s1 using @condition1;
--手工釋放,或者是 connection 關閉時谜喊, server 自動回收
deallocate prepare s1;