Upgrading fomr MySQL to MariaDB, stored procedure with union
Hello all,
I'm new here and to MySQL/MariaDB. Now changed jobs and have to work MySQL/MariaDB.
The first thing is to check upgrading MySQL 5.6.23 to MariaDB 10.3.9. So took a backup from the MySQL db ( a sql 8.8GB )
Now the scripts stops at creating a store procedure with a select - union in it. From the backup script:
CREATE DEFINER=`root`@`%` PROCEDURE `sp_s_persoon_bedrijf_werknemer`(
IN In_param1 varchar(30),
IN in_param2 varchar(30),
IN in_param3 varchar(30),
IN in_param4 varchar(30),
IN in_param5 varchar(30),
IN in_param6 varchar(30)
)
BEGIN
select * from `v_bedrijf`
where (zoekveld like concat('%',in_param1,'%') or in_param1 = '')
and (zoekveld like concat('%',in_param2,'%') or in_param2 = '')
and (zoekveld like concat('%',in_param3,'%') or in_param3 = '')
or (zoekveld like concat('%',in_param4,'%') and in_param4 <> '')
or (zoekveld like concat('%',in_param5,'%') and in_param5 <> '')
or (zoekveld like concat('%',in_param6,'%') and in_param6 <> '') limit 1000
union
select * from `v_personen`
where (zoekveld like concat('%',in_param1,'%') or in_param1 = '')
and (zoekveld like concat('%',in_param2,'%') or in_param2 = '')
and (zoekveld like concat('%',in_param3,'%') or in_param3 = '')
or (zoekveld like concat('%',in_param4,'%') and in_param4 <> '')
or (zoekveld like concat('%',in_param5,'%') and in_param5 <> '')
or (zoekveld like concat('%',in_param6,'%') and in_param6 <> '') limit 1000
union
select * from `v_werknemer`
where (zoekveld like concat('%',in_param1,'%') or in_param1 = '')
and (zoekveld like concat('%',in_param2,'%') or in_param2 = '')
and (zoekveld like concat('%',in_param3,'%') or in_param3 = '')
or (zoekveld like concat('%',in_param4,'%') and in_param4 <> '')
or (zoekveld like concat('%',in_param5,'%') and in_param5 <> '')
or (zoekveld like concat('%',in_param6,'%') and in_param6 <> '') limit 1000
;
END ;;
Just complains with: SQL Fout (1064): You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'unionselect * from `v_personen` where (zoekveld like concat('%',in_' at line 17
Some searching and trying found out there has to be () round the select statements. But also have to remove the Begin/End from the script. This seems strange to me.... Can someone explain?
I used MySQLWorkbench and Heidi for the small part of the script.
Kind reagrds,
Jan
Answer
This appears to work fine, with no need to remove the BEGIN or END:
DELIMITER //
CREATE OR REPLACE DEFINER=`root`@`%` PROCEDURE `sp_s_persoon_bedrijf_werknemer`(
IN In_param1 varchar(30),
IN in_param2 varchar(30),
IN in_param3 varchar(30),
IN in_param4 varchar(30),
IN in_param5 varchar(30),
IN in_param6 varchar(30)
)
BEGIN
(select * from `v_bedrijf`
where (zoekveld like concat('%',in_param1,'%') or in_param1 = '')
and (zoekveld like concat('%',in_param2,'%') or in_param2 = '')
and (zoekveld like concat('%',in_param3,'%') or in_param3 = '')
or (zoekveld like concat('%',in_param4,'%') and in_param4 <> '')
or (zoekveld like concat('%',in_param5,'%') and in_param5 <> '')
or (zoekveld like concat('%',in_param6,'%') and in_param6 <> '') limit 1000)
union
(select * from `v_personen`
where (zoekveld like concat('%',in_param1,'%') or in_param1 = '')
and (zoekveld like concat('%',in_param2,'%') or in_param2 = '')
and (zoekveld like concat('%',in_param3,'%') or in_param3 = '')
or (zoekveld like concat('%',in_param4,'%') and in_param4 <> '')
or (zoekveld like concat('%',in_param5,'%') and in_param5 <> '')
or (zoekveld like concat('%',in_param6,'%') and in_param6 <> '') limit 1000)
union
(select * from `v_werknemer`
where (zoekveld like concat('%',in_param1,'%') or in_param1 = '')
and (zoekveld like concat('%',in_param2,'%') or in_param2 = '')
and (zoekveld like concat('%',in_param3,'%') or in_param3 = '')
or (zoekveld like concat('%',in_param4,'%') and in_param4 <> '')
or (zoekveld like concat('%',in_param5,'%') and in_param5 <> '')
or (zoekveld like concat('%',in_param6,'%') and in_param6 <> '') limit 1000);
END;
//
DELIMITER ;