MySQL Stored Procedures: Create functions with error handling for repetitive tasks.

A previous blog post I wrote, INSERT with SELECT statement for columns with FOREIGN KEY constraint in MySQL with examples, we visited using INSERT with SELECT syntax adding records to one table, honoring FOREIGN KEY constraints in another. Constantly retyping that SELECT for each INSERT can be automated by ‘wrapping’ it up a function and that will be the focus for this blog post.

ground shot of multiple crowded building looking upwards

Photo by Steven Wei on Unsplash

Note: All data, names or naming found within the database presented in this post, are strictly used for practice, learning, instruction, and testing purposes. It by no means depicts actual data belonging to or being used by any party or organization.


***Update from original posting***
I am fortunate (and super grateful) that a reader, who couldn’t comment on my blog, due to some settings I had (hopefully are resolved) provided me terrific feedback, guidance, and corrections. I will leave the original post intact so other readers can see what the suggestions are because I would like to give this reader credit for taking the time to tweet me all his observations.
Here are links to the tweets with his fantastic observations if you would like to read them:

Appreciate it Georgi D. Sotirov !!!


OS and DB used:

  • Xubuntu Linux 16.04.3 LTS (Xenial Xerus)
  • MySQL 5.7.22

I’ll create a function named f_auth_ins that accepts one parameter of data type VARCHAR(255) to represent the author_name belonging to the id we need to match up with for the INSERT.

Let’s look at that function’s composition:

1
2
3
4
5
6
7
8
9
10
11
12
DELIMITER $$
CREATE FUNCTION f_auth_ins(p_author_name VARCHAR(255))
RETURNS INTEGER(11)
LANGUAGE SQL
BEGIN
    DECLARE v_auth_id INTEGER(11);
    DECLARE v_author_name VARCHAR(255);
    SET v_author_name := p_author_name;
    SELECT id INTO v_auth_id FROM author WHERE author_name = v_author_name;
    RETURN v_auth_id;
END $$
DELIMITER ;

Function f_auth_ins returns the matched id from table author by way of the INTEGER(11) return type in the function declaration.

Let’s now test f_auth_ins in this INSERT statement:

1
2
3
mysql> INSERT INTO joke(joke_text, joke_date, author_id)
    -> VALUES ('Wilber the pig is loud.', '1999-06-23', (SELECT f_auth_ins('Famous Anthony')));
Query OK, 1 row affected (0.05 sec)

And let’s verify the correct author_id is there:

1
2
3
4
5
6
7
8
mysql> SELECT * FROM joke
    -> WHERE joke_date = '1999-06-23';
+----+-------------------------+------------+-----------+
| id | joke_text               | joke_date  | author_id |
+----+-------------------------+------------+-----------+
| 13 | Wilber the pig is loud. | 1999-06-23 |         4 |
+----+-------------------------+------------+-----------+
1 row in set (0.00 sec)

Perfect.
We now avoid typing out that original SELECT statement by invoking the f_auth_ins function instead.
How does the function perform with a author_name that does not exist in the author table?
Let’s see.

1
2
3
mysql> INSERT INTO joke(joke_text, joke_date, author_id)
    -> VALUES('Three blind mice.', CURRENT_DATE(), (SELECT f_auth_ins('Johhny The Joker')));
Query OK, 1 row affected (0.03 sec)

What?!?
That INSERT didn’t fail?
But 'Johhny The Joker' is not in the author table.

1
2
3
4
5
6
7
8
9
10
mysql> SELECT * FROM author;
+----+----------------+------------------------+
| id | author_name    | author_email           |
+----+----------------+------------------------+
|  1 | Josh Otwell    | jotwell@email.com      |
|  2 | Jerome Smith   | jssmith@emailhouse.org |
|  3 | Casey Jones    | housing@email.org      |
|  4 | Famous Anthony | fam@fame.org           |
+----+----------------+------------------------+
4 rows in set (0.00 sec)

So what value was inserted?

1
2
3
4
5
6
7
8
mysql> SELECT * FROM joke
     > WHERE joke_date = CURRENT_DATE();
+----+-------------------+------------+-----------+
| id | joke_text         | joke_date  | author_id |
+----+-------------------+------------+-----------+
| 15 | Three blind mice. | 2018-06-19 |      NULL |
+----+-------------------+------------+-----------+
1 row in set (0.00 sec)

Very interesting.
We have to dig into this.
Let’s call the f_auth_ins function on a couple of author_name‘s we know are present in the table:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
mysql> SELECT f_auth_ins('Josh Otwell');
+---------------------------+
| f_auth_ins('Josh Otwell') |
+---------------------------+
|                         1 |
+---------------------------+
1 row in set (0.00 sec)

mysql> SELECT f_auth_ins('Casey Jones');
+---------------------------+
| f_auth_ins('Casey Jones') |
+---------------------------+
|                         3 |
+---------------------------+
1 row in set (0.00 sec)

Those two author’s are present and return the correct id‘s.
Now, test an author_name not present:

1
2
3
4
5
6
7
mysql> SELECT f_auth_ins('Joker Jonesy');
+----------------------------+
| f_auth_ins('Joker Jonesy') |
+----------------------------+
|                       NULL |
+----------------------------+
1 row in set (0.00 sec)

This definitely stems from the function and needs to be re-factored.
We’ll DROP the existing function first:

1
2
mysql> DROP FUNCTION f_auth_ins;
Query OK, 0 rows affected (0.08 sec)

Here is the improved function that will notify us if we try to INSERT an author_id that has a non-existent match in table author. Notice the author_name column and v_author_name procedure variables are both compared in their all uppercase equivalents.

This rectifies any problems or issues with letter case in the names. Even should all lower, or a mix of upper and lower case letters be supplied in the function call:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
DELIMITER $$
CREATE FUNCTION f_auth_ins(p_author_name VARCHAR(255))
RETURNS INTEGER(11)
LANGUAGE SQL
BEGIN
    DECLARE v_auth_id INTEGER(11);
    DECLARE v_author_name VARCHAR(255);
    DECLARE v_counter INTEGER(11);
    SET v_author_name := p_author_name;
    SELECT COUNT(id) INTO v_counter FROM author WHERE UPPER(author_name) = UPPER(v_author_name);
    IF v_counter <> 1 THEN
        SIGNAL SQLSTATE '42000'
        SET MESSAGE_TEXT = 'Author name not found in author table.';
    ELSE
        SELECT id INTO v_auth_id FROM author WHERE UPPER(author_name) = UPPER(v_author_name);
        RETURN v_auth_id;
    END IF;
END $$
DELIMITER ;

Let’s test out the updated function using a known author and confirm that functionality still works:

1
2
3
mysql> INSERT INTO joke(joke_text, joke_date, author_id)
     > VALUES ('Hurry up we are a freezin', CURRENT_DATE, (SELECT f_auth_ins('Casey Jones')));
Query OK, 1 row affected (0.02 sec)

No problems there.
And with an author_name not present in table author?

1
2
3
mysql> INSERT INTO joke(joke_text, joke_date, author_id)
     > VALUES('Hurry up we are a freezin', CURRENT_DATE, (SELECT f_auth_ins('Dirty Harry Jones')));
ERROR 1644 (42000): Author name not found in author table.

Awesome sauce.
Now we will get an error message instead of NULL being inserted.
So how does this work?

Let’s look at 2 key lines in this improved version of f_auth_ins.
This statement is integral for the desired outcome:

1
SELECT COUNT(id) INTO v_counter FROM author WHERE UPPER(author_name) = UPPER(v_author_name);

Here we are selecting COUNT(id) of the matching id from table author into the v_counter variable for the p_author_name parameter passed in.
Then on the next line in the IF conditional here:

1
IF v_counter <> 1 THEN

We check that variable. Should the author_name exist, this variable’s value will be 1 and execution skips from here to the ELSE segment of the block, ultimately returning the v_auth_id to the caller for INSERT.

However, if v_counter is not equal to 1, there is no match for that author_name in table author.
And we get the MESSAGE_TEXT notification returned to the caller instead, notifying them that the author was not found.


* Note: Shout-out to this great blog post/tutorial I found informative and helpful, as I figured out this particular Stored Procedure/Function.


Here is the SQLSTATE directly from the documentation we used:
“Error: 1065 SQLSTATE: 42000 (ER_EMPTY_QUERY)
Message: Query was empty”

With this function in place, our INSERT with SELECT‘s are better automated, in addition to providing a means of error handling for any author_name‘s that do not yet exist in the author table.
Feel free to leave any comments below. I would love you hear from you all.
Explore the official MySQL 5.7 On-line Manual for questions and more information.

A Call To Action!

Thank you for taking the time to read this post. I truly hope you discovered something interesting and enlightening. Please share your findings here, with someone else you know who would get the same value out of it as well.

Visit the Portfolio-Projects page to see blog post/technical writing I have completed for clients.

Have I mentioned how much I love a cup of coffee?!?!

To receive email notifications (Never spam) from this blog (“Digital Owl’s Prose”) for the latest blog posts as they are published, please subscribe (of your own volition) by clicking the ‘Click To Subscribe!’ button in the sidebar on the homepage! (Feel free at any time to review the Digital Owl’s Prose Privacy Policy Page for any questions you may have about: email updates, opt-in, opt-out, contact forms, etc…)

Be sure and visit the “Best Of” page for a collection of my best blog posts.


Josh Otwell has a passion to study and grow as a SQL Developer and blogger. Other favorite activities find him with his nose buried in a good book, article, or the Linux command line. Among those, he shares a love of tabletop RPG games, reading fantasy novels, and spending time with his wife and two daughters.


Disclaimer: The examples presented in this post are hypothetical ideas of how to achieve similar types of results. They are not the utmost best solution(s). The majority, if not all, of the examples provided are performed on a personal development/learning workstation-environment and should not be considered production quality or ready. Your particular goals and needs may vary. Use those practices that best benefit your needs and goals. Opinions are my own.

One thought on “MySQL Stored Procedures: Create functions with error handling for repetitive tasks.

Hey thanks for commenting! Leave a Reply

This site uses Akismet to reduce spam. Learn how your comment data is processed.