Click here to Skip to main content
15,886,137 members
Please Sign up or sign in to vote.
0.00/5 (No votes)
See more:
DELIMITER //

DROP PROCEDURE IF EXISTS uppercasecol //

CREATE PROCEDURE uppercasecol(IN tblname VARCHAR(200))
BEGIN
DECLARE done INT DEFAULT 0;
DECLARE oldname VARCHAR(200);
DECLARE cur CURSOR FOR SELECT COLUMN_NAME FROM INFORMATION_SCHEMA.COLUMNS
WHERE TABLE_SCHEMA='ADM01' AND TABLE_NAME=tblname;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = 1;
OPEN cur;
REPEAT
FETCH cur INTO oldname;
SET @newname = UPPER(oldname);
#IF newname equals to oldname, do nothing;
#select 'a' <> 'A'; -> 0
#select 'a' <> BINARY 'A'; -> 1
SET @isNotSame = @newname <> BINARY oldname;
IF NOT done && @isNotSame THEN
SET @SQL = CONCAT('ALTER TABLE `',tblname,'` CHANGE COLUMN `',oldname,'` @newname');
PREPARE tmpstmt FROM @SQL;
EXECUTE tmpstmt;
DEALLOCATE PREPARE tmpstmt;
END IF;
UNTIL done END REPEAT;
CLOSE cur;
END //
DELIMITER ;
CALL uppercasecol('USER_MODULE');

I am using the above code to convert the column names to upper case but the code is giving error 1604(42000) in CONCAT('ALTER TABLE `',tblname,'` CHANGE COLUMN `',oldname,'` @newname'). Can anyone help me out in this...

thanx in advance
Posted
Updated 10-Sep-15 22:14pm
v3

1 solution

There was some errors.
this should work.

SQL
BEGIN 
 DECLARE done INT DEFAULT 0; 
 DECLARE oldname VARCHAR(200); 
 DECLARE datatype VARCHAR(200); 
 DECLARE cur CURSOR FOR SELECT COLUMN_NAME, COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS 
 WHERE TABLE_SCHEMA='ADM01' AND TABLE_NAME=tblname;

 DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = 1; 
 OPEN cur; 
 
 REPEAT 
   FETCH cur INTO oldname, datatype; 
   SET @newname = UPPER(oldname); 
   SET @isNotSame = @newname <> BINARY oldname; 

   IF NOT done && @isNotSame THEN 

     SET @SQL = CONCAT('ALTER TABLE `', tblname, '` CHANGE COLUMN `', oldname, '` `', @newname, '`', datatype); 
 
     PREPARE tmpstmt FROM @SQL; 
     EXECUTE tmpstmt; 
     DEALLOCATE PREPARE tmpstmt; 

   END IF;

 UNTIL done END REPEAT; 

 CLOSE cur; 

 SELECT 'OK' FROM DUAL;
 
END


The last line
SQL
SELECT 'OK' FROM DUAL 
will show you if the procedure will end correctly.

Compare the concat function to find your error.

When you have an error in procedure and you can't debug, try to remove lines of code and re execute it to find the offending line/s, or substitute the variable with constant to see if all works as expected.

To find your error I made the procedure return also the result of concat:
SQL
SELECT
CONCAT('ALTER TABLE `', tblname, '` CHANGE COLUMN `', oldname, '` `', @newname, '`', datatype)
FROM DUAL

So I found, also, that the statement you dynamically execute was incorrect.

F.
 
Share this answer
 

This content, along with any associated source code and files, is licensed under The Code Project Open License (CPOL)



CodeProject, 20 Bay Street, 11th Floor Toronto, Ontario, Canada M5J 2N8 +1 (416) 849-8900