MySQL Camp Free Ride goes to Adam Ritter

And, the winner is……

Adam Ritter, of Nashville, Tennessee has been selected by Proven Scaling for a free ride to MySQL Camp!

Adam’s enthusiasm and very quick (within the first few hours of my original post), yet courteous and complete entry impressed us. His excitement to learn, and professionalism sealed the deal. Here’s an excerpt from his entry:

My name is Adam Ritter and I’m a recent Computer Science graduate from UT Knoxville. I’m currently looking for a job and I realized that being a DBA is what I want to do. I had started working with MySQL back in a course on Database Design and Management course I took in school. This course started the fire inside of me but unfortunately, it was over all too soon and I was left wanting to learn more. I’ve read through every intermediate MySQL source I could find, but I’m looking for as much advanced and expert level topics as I can find. I’ve worked on projects utilizing MySQL and have grown very fond of it.

If you’re attending MySQL Camp in a few weeks time, be sure to say hello to Adam!

Thanks, everyone! Keep an eye on my blog early next year for a similar offer for MySQL Conference & Expo 2007!

Want a Free Ride to MySQL Camp?

Have you heard of MySQL Camp at Google HQ in Mountain View, California, November 10-12?

Want to go? Can’t go because it’s out in sunny (ha, ha) California, hundreds or thousands of miles/kilometers from where you live?

Maybe you’re a bright student, or maybe you’re currently unemployed, or maybe you’ve got a job, but you just can’t afford to jet out to Mountain View for the weekend. Maybe you contribute code, bug fixes, tools; maybe you run a MySQL Meetup, and just can’t bear the airfare.

Proven Scaling would like to sponsora one such person to attend MySQL Camp! We’ll pay for your airfare and hotel—meals and transportation are on you. If you think you are qualified, you live somewhere in the USA or Canadab and you know you can make the trip, send us (with “MySQL Camp Free Ride” in the subject) the following information:

  • Your full, real name
  • Your blog or website, if any
  • Your company, school, or organization, if any
  • Your location, and closest airport
  • Any contributions you’ve made to MySQL or the MySQL community in the form of code, bug fixes, time, or otherwise
  • Why you feel you are the best or most qualified person for Proven Scaling to sponsor to MySQL Camp
  • Anything else you’d us like to know about yourself as we consider who to sponsor

However, you’d better hurry as you have only the next 60 hours or so to submit your proposal — no proposals will be accepted after midnight Pacific Daylight Time (GMT-8), Friday, October 20, 2006.

Good luck!

Update: Extended (and clarified) the deadline to midnight Friday instead of Thursday morning. Just to be clear: anyone is eligible, not just students.

a And, we’d encourage other companies attending or sponsoring MySQL Camp to do the same!

b If you live elsewhere, such as Europe, and you think you can get to the Bay Area fairly cheaply (lets say, under 1000 USD or so), or if you are just super qualified, feel free to send us your proposal anyway, and include how you propose to get to Mountain View cost effectively.

On Triggers, Stored Procedures, and Call Stacks

If you’re a frequent reader, you might have noticed that I’m on a roll contributing MySQL patches by now… there are many more to come. This is part of the reason that I founded Proven Scaling — to be able to spend my time solving interesting problems and making MySQL better. So what about triggers, stored procedures, and call stacks?

I’ve written a patch that implements three new functions in MySQL 5.01:

  • CALLER(level) — Returns the SQL statement in the call stack at level, where 0 is the level containing the call to CALLER() itself (which is nearly useless), and 1 and above are any stored procedure or trigger calls that got us here.
  • CALLER_DEPTH() — Returns the current depth of the call stack, not counting 0. CALLER(CALLER_DEPTH()) will always return the top-most level (i.e. the user-generated command).
  • CALLER_WS(separator, level) — Returns the entire call stack starting at level, with each level separated by separator.

What are these good for? Quite a bit! For a few examples:

  • Debugging — From any place in your stored procedure code, you can now find out how exactly you got there, no matter how complex the code is. In the future, this could be augmented by allowing you to see the values of the parameters at each step as well.
  • Auditing — This is much more interesting for most people, and while the current implementation isn’t perfect2, it’s getting a lot closer to what people need for auditing purposes. Using triggers and CALLER(), USER(), and NOW() you can get most of the auditing information you may need.

Now, for some examples of the output from these new functions:

Just a test of CALLER() and CALLER_DEPTH():

mysql> select caller(0);
+------------------+
| caller(0)        |
+------------------+
| select caller(0) | 
+------------------+
1 row in set (0.00 sec)

mysql> select caller_depth();
+----------------+
| caller_depth() |
+----------------+
|              0 | 
+----------------+
1 row in set (0.00 sec)

In order to get anything interesting, we need to generate some depth of the call stack:

delimiter //
create procedure stack() begin select caller_ws(' <called by> ', 1); end //
create procedure ts1() begin call stack(); end //
create procedure ts2() begin call ts1(); end //
create procedure ts3() begin call ts2(); end //

Now we can try it out for real:

mysql> call ts2()//
+------------------------------------------------------------+
| caller_ws(' <called by> ', 1)                              |
+------------------------------------------------------------+
| call stack() <called by> call ts1() <called by> call ts2() | 
+------------------------------------------------------------+
1 row in set (0.00 sec)

As an example of what you can do inside stored procedures:

DROP PROCEDURE IF EXISTS test.dump_stack //
CREATE DEFINER='root'@'localhost' PROCEDURE test.dump_stack ()
BEGIN
  DECLARE i INT DEFAULT 1;
  DECLARE caller_depth INT DEFAULT 0;
  SET caller_depth = CALLER_DEPTH();

  CREATE TEMPORARY TABLE test_stack_t (
    depth INT NOT NULL,
    query TEXT, 
    PRIMARY KEY (depth)
  );
  WHILE i <= caller_depth
  DO
    INSERT INTO test_stack_t (depth, query) VALUES (i, caller(i+1));
    SET i = i + 1;
  END WHILE;
  SELECT depth, query FROM test_stack_t ORDER BY depth DESC;
  DROP TEMPORARY TABLE test_stack_t;
END
//

We can then redefine stack() to call dump_stack() instead, so that we can use the same tsX() procedures above:

drop procedure if exists stack //
create procedure stack() begin call dump_stack(); end //

And the same test:

mysql> call ts2()//
+-------+--------------+
| depth | query        |
+-------+--------------+
|     3 | call ts2()   | 
|     2 | call ts1()   | 
|     1 | call stack() | 
+-------+--------------+
3 rows in set (0.00 sec)

With a little additional magic, we can use CALLER() for auditing2:

DROP TABLE IF EXISTS test.audit //
CREATE TABLE test.audit (
  id INT NOT NULL auto_increment,
  ts DATETIME,
  user CHAR(64), 
  call_stack TEXT, 
  PRIMARY KEY (id), 
  INDEX (ts), 
  INDEX (user)
)
//

DROP PROCEDURE IF EXISTS test.audit //
CREATE DEFINER='root'@'localhost' PROCEDURE test.audit ()
BEGIN
  INSERT INTO test.audit (ts, user, call_stack)
  VALUES (now(), user(), caller_ws(' <called by> ', 2));
END
//

DROP TABLE IF EXISTS test.test //
CREATE TABLE test.test (
  c CHAR(50)
)
//

CREATE DEFINER='root'@'localhost' TRIGGER test_test_b_i
BEFORE INSERT ON test.test 
FOR EACH ROW CALL test.audit()
//

CREATE DEFINER='root'@'localhost' PROCEDURE addtest(in in_c char(50))
BEGIN
  INSERT INTO test.test (c) VALUES (in_c);
END
//

And, let’s try it out:

mysql> INSERT INTO test.test (c) VALUES ('jeremy') //
Query OK, 1 row affected (0.01 sec)

mysql> SELECT * FROM test.audit //
+----+---------------------+---------------+---------------------------------------------+
| id | ts                  | user          | call_stack                                  |
+----+---------------------+---------------+---------------------------------------------+
|  4 | 2006-10-01 18:07:39 | root@dhcp-100 | INSERT INTO test.test (c) VALUES ('jeremy') |
+----+---------------------+---------------+---------------------------------------------+
1 row in set (0.00 sec)

mysql> CALL addtest('monty') //
Query OK, 1 row affected (0.00 sec)

mysql> SELECT * FROM test.audit //
+----+---------------------+---------------+---------------------------------------------------------------------------+
| id | ts                  | user          | call_stack                                                                |
+----+---------------------+---------------+---------------------------------------------------------------------------+
|  4 | 2006-10-01 18:07:39 | root@dhcp-100 | INSERT INTO test.test (c) VALUES ('jeremy')                               |
|  5 | 2006-10-01 18:11:26 | root@dhcp-100 | INSERT INTO test.test (c) VALUES (in_c) <called by> CALL addtest('monty') |
+----+---------------------+---------------+---------------------------------------------------------------------------+
2 rows in set (0.01 sec)

Let me know what you think!

1 Specifically mysql-5.0.25-nightly-20060823.

2 Currently, triggers are missing three important features to make them really useful for auditing: a way to find the call stack (which this patch addresses), the ability to have multiple triggers per type per table (currently MySQL only allows one trigger per table per type [before update, after insert, etc.]), and per-statement triggers (currently MySQL only has per-row triggers).

Followup: On IPs, hostnames, and MySQL

Back in April, I wrote On IPs, hostnames, and MySQL, which described the (sometimes surprising) ways in which MySQL deals with IP addresses, hostnames, and privileges, as well as some basics about the host cache itself. In a footnote to that post, I mentioned a patch I had written against MySQL 4.1 to give some more visibility into the host cache.

Over the past two days, I have worked on porting that patch to MySQL 5.01, 2, and making some fairly large improvements to it. The patch implements a few things:

  1. Configurable Size — Without the patch, the size of the cache is fixed at 128 entries, and can only be changed by changing a #define and recompiling. You may now tune the size of the host cache using SET GLOBAL host_cache_size=X.
  2. Metrics — You may now see how well the cache is performing using SHOW GLOBAL STATUS LIKE 'Host%'. (See example below.)
  3. Display — You may now see the complete contents of the cache using SHOW HOST CACHE. (See example below.)

The above new features should give MySQL DBAs much better insight into what’s happening in their MySQL server, in an area where there has historically been very little information and a lot of misunderstandings.

Now, for the examples:

SHOW GLOBAL STATUS LIKE 'Host%'

mysql> show status like 'host%';
+--------------------+-------+
| Variable_name      | Value |
+--------------------+-------+
| Host_cache_free    | 127   | 
| Host_cache_hits    | 2     | 
| Host_cache_inserts | 1     | 
| Host_cache_misses  | 1     | 
| Host_cache_prunes  | 0     | 
| Host_cache_used    | 1     | 
+--------------------+-------+
6 rows in set (0.01 sec)

SHOW HOST CACHE

mysql> show host cache;
+-----------+----------+--------+------+
| IP        | Hostname | Errors | Hits |
+-----------+----------+--------+------+
| 10.0.0.22 | hiriko   |      0 |    2 | 
+-----------+----------+--------+------+
1 row in set (0.00 sec)

Enjoy!

1 Hopefully this will be accepted into MySQL 5.0. Brian?

2 The patch is against mysql-5.0.25-nightly-20060823 specifically.