- MySQL Naming Rules
- The Server SQL Mode
- Character Set Support
- Selecting, Creating, Dropping, and Altering Databases
- Creating, Dropping, Indexing, and Altering Tables
- Getting Information About Databases and Tables
- Performing Multiple-Table Retrievals with Joins
- Performing Multiple-Table Retrievals with Subqueries
- Performing Multiple-Table Retrievals with UNION
- Multiple-Table Deletes and Updates
- Performing Transactions
- Foreign Keys and Referential Integrity
- Using FULLTEXT Searches
- New Features in MySQL 5.0
New Features in MySQL 5.0
This section discusses some of the important new features that are being developed in MySQL 5.0:
Views
Stored Procedures and Functions
Triggers
These are all recent additions, so this section is relatively brief to provide just an overview. Because the capabilities described here are new, you may encounter limitations. However, development is ongoing, so as these features mature and restrictions are eased, their usefulness will increase.
Using Views
A view is a virtual table. That is, it acts like a table but actually contains no data. Instead, it is defined in terms of tables (or other views) and provides alternative ways to look at table data. Often this can simplify applications. Views were introduced in MySQL 5.0.1.
A simple view can be nothing more than a way to select a subset of a table's columns. Suppose that you often want to select only the last_name, first_name, city, and state columns from the president table, but you don't want to write out all the columns like this:
SELECT last_name, first_name, city, state FROM president;
Nor do you want to use SELECT *. That's easier to write, but * retrieves columns that you don't want. The solution is to define a view that retrieves only the desired columns:
CREATE VIEW vpres AS SELECT last_name, first_name, city, state FROM president;
Now the view acts as a "window" into just those columns that you want to see. This means that you can use SELECT * with the view and get back only the columns named in the view definition:
mysql> SELECT * FROM vpres; +------------+---------------+---------------------+-------+ | last_name | first_name | city | state | +------------+---------------+---------------------+-------+ | Washington | George | Wakefield | VA | | Adams | John | Braintree | MA | | Jefferson | Thomas | Albemarle County | VA | | Madison | James | Port Conway | VA | | Monroe | James | Westmoreland County | VA | ...
If you include a WHERE clause, MySQL adds it to the view definition when executing the statement to further restrict the result:
mysql> SELECT * FROM vpres WHERE last_name = 'Adams'; +-----------+-------------+-----------+-------+ | last_name | first_name | city | state | +-----------+-------------+-----------+-------+ | Adams | John | Braintree | MA | | Adams | John Quincy | Braintree | MA | +-----------+-------------+-----------+-------+
The same is true if you add ORDER BY, LIMIT, and so forth.
When you use a view, you can refer only to those columns named in the view definition. That is, you cannot refer to a column that is not part of the view:
mysql> SELECT * FROM vpres WHERE suffix <> ''; ERROR 1054 (42S22): Unknown column 'suffix' in 'where clause'
The column names for a view by default are those named in the output column list of its SELECT statement. To provide column names explicitly, add a list of names in parentheses following the view name in the view definition:
mysql> CREATE VIEW vpres2 (ln, fn) AS -> SELECT last_name, first_name FROM president;
Now when you refer to the view, you must use the given column names rather than the names in the SELECT:
mysql> SELECT last_name, first_name FROM vpres2; ERROR 1054 (42S22) at line 1: Unknown column 'last_name' in 'field list' mysql> SELECT ln, fn FROM vpres2; +------------+---------------+ | ln | fn | +------------+---------------+ | Washington | George | | Adams | John | | Jefferson | Thomas | | Madison | James | | Monroe | James | ...
A view can be used to perform calculations automatically. In Chapter 1, we developed a statement that determines the age of presidents at death. The same calculation can be incorporated into a view definition:
mysql> CREATE VIEW pres_age AS -> SELECT last_name, first_name, birth, death, -> (YEAR(death) - YEAR(birth)) -> - IF(RIGHT(death,5) < RIGHT(birth,5),1,0) -> AS age -> FROM president;
This view includes an age column that is defined as a calculation, and selecting that column from the view retrieves the results of the calculation:
mysql> SELECT * FROM pres_age; +------------+---------------+------------+------------+------+ | last_name | first_name | birth | death | age | +------------+---------------+------------+------------+------+ | Washington | George | 1732-02-22 | 1799-12-14 | 67 | | Adams | John | 1735-10-30 | 1826-07-04 | 90 | | Jefferson | Thomas | 1743-04-13 | 1826-07-04 | 83 | | Madison | James | 1751-03-16 | 1836-06-28 | 85 | | Monroe | James | 1758-04-28 | 1831-07-04 | 73 | ...
By including the age calculation in the view definition, it's no longer necessary to write out the formula to see the age values. The view hides the details.
A view can refer to multiple tables, which makes it easier to run queries that involve joins. The following view looks up scores, joining them with student and grade event information:
mysql> CREATE VIEW vstudent AS -> SELECT student.student_id, name, date, score, category -> FROM grade_event, score, student -> WHERE -> grade_event.event_id = score.event_id -> AND score.student_id = student.student_id;
When you select from the view, MySQL executes the join and returns information from multiple tables:
mysql> SELECT * FROM vstudent; +------------+-----------+------------+-------+----------+ | student_id | name | date | score | category | +------------+-----------+------------+-------+----------+ | 1 | Megan | 2004-09-03 | 20 | Q | | 3 | Kyle | 2004-09-03 | 20 | Q | | 4 | Katie | 2004-09-03 | 18 | Q | | 5 | Abby | 2004-09-03 | 13 | Q | | 6 | Nathan | 2004-09-03 | 18 | Q | | 7 | Liesl | 2004-09-03 | 14 | Q | | 8 | Ian | 2004-09-03 | 14 | Q | ...
The view makes it trivial to retrieve the scores for a particular student by name:
mysql> SELECT * FROM vstudent WHERE name = 'emily'; +------------+-------+------------+-------+----------+ | student_id | name | date | score | category | +------------+-------+------------+-------+----------+ | 31 | Emily | 2004-09-03 | 11 | Q | | 31 | Emily | 2004-09-06 | 19 | Q | | 31 | Emily | 2004-09-09 | 81 | T | | 31 | Emily | 2004-09-16 | 19 | Q | | 31 | Emily | 2004-09-23 | 9 | Q | | 31 | Emily | 2004-10-01 | 76 | T | +------------+-------+------------+-------+----------+
Some views are updatable, which means that you can insert, update, and delete rows in the underlying table by means of operations on the view. Here is a simple example:
mysql> CREATE TABLE t (i INT); mysql> INSERT INTO t (i) VALUES(1),(2),(3); mysql> CREATE VIEW v AS SELECT i FROM t; mysql> SELECT i FROM v; +------+ | i | +------+ | 1 | | 2 | | 3 | +------+ mysql> INSERT INTO v (i) VALUES(4); mysql> DELETE FROM v WHERE i < 3; mysql> SELECT i FROM v; +------+ | i | +------+ | 3 | | 4 | +------+ mysql> UPDATE v SET i = i + 1; mysql> SELECT i FROM v; +------+ | i | +------+ | 4 | | 5 | +------+
For a view to be updatable, it must map directly onto a single table, it must select only columns that are simple references to table columns (not arbitrary expressions), and any operation on a view row must correspond to an operation on a single row in the underlying table. For example, if a view involves a summary calculated using an aggregate function, each view row can be based on multiple underlying table rows. In this case, the view is not updatable because there is no way to tell which underlying table row should be updated.
Using Stored Procedures
Beginning with MySQL 5.0.0, it is possible to define stored routines. These are functions and procedures that are stored on the server side and that can be invoked later. Stored functions return a result and can be included in expressions just like built-in functions. Stored procedures do not return a result directly. However, they support parameter types that can have their values set in the body of the procedure such that the values can be accessed by the caller after the procedure finishes.
Generally, you use a function to calculate a value to be returned to the caller for use in expressions. Use a procedure if you need only to invoke a routine to produce an effect or action without returning a value. These are guidelines, not hard and fast rules. For example, if you need to return more than one value, you cannot use a function. But you can define a procedure that has OUT parameters that can be used in expressions after the procedure returns.
Stored routines provide the following benefits and capabilities:
-
They extend SQL syntax to include looping and branching statements. (The syntax for all stored routine statements is given in Appendix E.)
-
They provide a mechanism for handling errors.
-
Because they are stored on the server side, all the code needed to define them need be sent over the network only once at routine creation time, not each time you invoke them. This reduces overhead.
-
They provide a means to standardize computational operations. By providing a set of stored routines as a "library" that many applications can use, those applications all perform the operations in the same way.
To create a stored function or procedure, use a CREATE FUNCTION or CREATE PROCEDURE statement. The following example creates a function. In the preceding section on views, we defined a view that included a column that performed an age calculation for the rows in the president table. If you want to use such a calculation more generally than in the context of a particular view, define the calculation as a function so that you can invoke it in arbitrary expressions.
mysql> delimiter $ mysql> CREATE FUNCTION age (date1 DATE, date2 DATE) -> RETURNS INT -> BEGIN -> DECLARE age INT; -> SET age = (YEAR(date2) - YEAR(date1)) -> - IF(RIGHT(date2,5) < RIGHT(date1,5),1,0); -> RETURN age; -> END$ mysql> delimiter ;
The function begins with a RETURNS clause to indicate the data type of its return value. This is followed by the function body. Because the body consists of multiple statements, they're enclosed within a BEGIN/END block. The body declares a local variable, assigns the result of the calculation to it, and returns it as the function value. A function body must include at least one RETURN statement to return a value to the caller. (This function could have been written more concisely to use return the calculation result directly from the RETURN statement, but I wanted to illustrate variable declaration and use.)
The age() function takes two DATE arguments and can be invoked like any built-in function:
mysql> SELECT first_name, last_name, birth, death, age (birth, death) -> FROM president; +---------------+------------+------------+------------+-------------------+ | first_name | last_name | birth | death | age(birth, death) | +---------------+------------+------------+------------+-------------------+ | George | Washington | 1732-02-22 | 1799-12-14 | 67 | | John | Adams | 1735-10-30 | 1826-07-04 | 90 | | Thomas | Jefferson | 1743-04-13 | 1826-07-04 | 83 | | James | Madison | 1751-03-16 | 1836-06-28 | 85 | | James | Monroe | 1758-04-28 | 1831-07-04 | 73 | ...
Actually, there is one difference between how you refer to stored functions and built-in functions. For a stored function, the opening parenthesis need not immediately follow the function name. In fact, if you give a stored function the same name as a built-in function, you must have a space between the name and the parenthesis (both when you define the function and when you invoke it).
In the preceding example, notice the delimiter commands surrounding the function definition statement. If a routine body consists of a single statement, you can write it at the end of the CREATE FUNCTION or CREATE PROCEDURE statement with no special treatment. However, if a routine body consists of multiple statements, each must be terminated by semicolon (';'). That also is the default statement terminator for the mysql program, which introduces a conflict. To deal with this, use the delimiter command to redefine mysql's statement delimiter to a character or string that does not appear in the routine definition. That causes mysql not to interpret semicolons as terminators and to pass the entire definition to the server as a single statement. You can redefine the terminator to semicolon again after defining the routine.
A stored procedure is similar to a stored function, but it doesn't return a value. Therefore, it does not include a RETURNS clause or any RETURN statements. Here is a simple stored procedure that takes one argument, a year, and displays information for presidents born in that year:
mysql> DROP PROCEDURE IF EXISTS born_in_year; mysql> CREATE PROCEDURE born_in_year (year_of_birth INT) -> SELECT first_name, last_name, birth, death -> FROM president -> WHERE YEAR(birth) = year_of_birth;
In this case, the body of the routine consists of a single statement, so no delimiter commands are necessary. The procedure issues a SELECT statement. The results of this statement are not returned as the procedure value, but instead are passed as a result set to the client. To see this, invoke the procedure, which is done by using CALL:
mysql> CALL born_in_year(1908); +------------+-----------+------------+------------+ | first_name | last_name | birth | death | +------------+-----------+------------+------------+ | Lyndon B. | Johnson | 1908-08-27 | 1973-01-22 | +------------+-----------+------------+------------+ mysql> CALL born_in_year(1913); +------------+-----------+------------+------------+ | first_name | last_name | birth | death | +------------+-----------+------------+------------+ | Richard M | Nixon | 1913-01-09 | 1994-04-22 | | Gerald R | Ford | 1913-07-14 | NULL | +------------+-----------+------------+------------+
The example illustrates one thing that stored procedures can do that stored functions in MySQL currently cannot: Procedures can access tables. This prohibition on referring to tables in stored functions presumably will be lifted in the future. As a workaround for this limitation on functions, you can define a procedure that performs the required table operation, and include in the definition an OUT or INOUT parameter to send back as the procedure "value" when the procedure returns. This technique also can be useful if you need to return more than one value, because functions return only a single value.
By default, a procedure parameter is an IN parameter. The caller passes a value, and it can be modified within the procedure, but any changes are not visible to the caller after the procedure returns. An OUT parameter is the opposite. The procedure assigns a value to the parameter, which can be accessed by the caller after the procedure returns. An INOUT parameter allows the caller to pass in a value, and to get a value back.
The following example is similar to the preceding one, but instead of displaying columns from president table rows, it simply counts the number of rows and assigns the count to an OUT parameter. The caller gets the count from that parameter after invoking the procedure.
mysql> delimiter $ mysql> CREATE PROCEDURE count_born_in_year -> (year_of_birth INT, OUT how_many INT) -> BEGIN -> DECLARE c CURSOR FOR -> SELECT COUNT(*) FROM president WHERE YEAR(birth) = year_of_birth; -> OPEN c; -> FETCH c INTO how_many; -> CLOSE c; -> END$ mysql> delimiter ; mysql> CALL count_born_in_year(1908, @count); mysql> SELECT @count; +--------+ | @count | +--------+ | 1 | +--------+ mysql> CALL count_born_in_year(1913, @count); mysql> SELECT @count; +--------+ | @count | +--------+ | 2 | +--------+
The procedure does not simply invoke the SELECT statement and assign the value of the COUNT(*) column to a variable. If it did that, the result of the statement would be displayed to the client directly. To suppress this display, the procedure sets up a cursor and uses it to execute the SELECT statement. This way the result of the SELECT goes to the procedure itself so that it can process the result directly.
To use a cursor, declare it to associate it with the statement to be executed. Then open the cursor, fetch the rows of the statement, and close the cursor. In many applications, the FETCH statement will appear inside some kind of a loop construct such as a REPEAT statement. However, in the count_born_in_year() procedure, the SELECT returns only a single row and there is no need for a loop.
To invoke the procedure, pass a year value as the first parameter, and provide a variable into which the count should be placed as the second parameter. After the procedure returns, the variable value will contain the count.
Using Triggers
Trigger support is available as of MySQL 5.0.2. A trigger can be defined to activate for INSERT, DELETE, or UPDATE statements for a table, and can be set to activate either before or after each row processed by the statement. The trigger definition includes a statement that executes when the trigger activates. Currently, there are no trigger-specific privileges, so you must have the SUPER privilege to define a trigger.
Triggers in MySQL currently have the same limitation as stored functions that they cannot refer to tables in general. They can refer only to the values in the current row being modified in the table that is associated with the trigger. This lessens the usefulness of triggers for certain applications. For example, you cannot perform change logging by recording deletes, inserts, and updates for a table to maintain a change history. Nevertheless, even in their current early implementation, triggers offer some important features:
-
A trigger can examine the current contents of a row before it is deleted or updated.
-
A trigger can examine new data values to be inserted or used to update a row.
-
In a BEFORE trigger, the trigger can change the new values before they are stored in the database, which enables you to perform data filtering.
The following example shows a trigger for INSERT statements for a table t. It is a BEFORE trigger so that it can examine data values before they are inserted into the table. The trigger performs two actions:
-
The trigger checks for attempts to insert negative numbers into the table's integer column and converts them to zero instead.
-
The trigger automatically provides a value of NOW() for the DATETIME column. In effect, this works around the limitation that a column's default value must be a constant, and implements TIMESTAMP-like automatic initialization for a DATETIME column.
mysql> CREATE TABLE t (i INT, dt DATETIME); mysql> delimiter $ mysql> CREATE TRIGGER t_ins BEFORE INSERT ON t -> FOR EACH ROW BEGIN -> SET NEW.dt = CURRENT_TIMESTAMP; -> IF NEW.i < 0 THEN SET NEW.i = 0; END IF; -> END$ mysql> delimiter ; mysql> INSERT INTO t (i) VALUES(-2),(0),(2); mysql> SELECT * FROM t; +------+---------------------+ | i | dt | +------+---------------------+ | 0 | 2005-01-23 12:14:11 | | 0 | 2005-01-23 12:14:11 | | 2 | 2005-01-23 12:14:11 | +------+---------------------+
In the same way as for stored routines, the body of a trigger can contain multiple statements if you enclose them within a BEGIN/END block. In this case, you'll need to change the default delimiter so that you can use ';' as the delimiter within the trigger definition. The preceding example uses this technique.
The syntax NEW.col_name can be used in the trigger body to refer to columns in the new row to be inserted or updated in an INSERT or UPDATE trigger. Similarly, OLD.col_name can be used to refer to columns in the old row to be deleted or updated in a DELETE or UPDATE trigger. OLD and NEW are not case sensitive.
Triggers can refer to user variables, so you can set a variable within a trigger to pass a result outside of the trigger. This gives you a way to check what effect the trigger had.