CREATE
[DEFINER = { user | CURRENT_USER }]
TRIGGER trigger_name
trigger_time trigger_event
ON tbl_name FOR EACH ROW
trigger_body
trigger_time: { BEFORE | AFTER }
trigger_event: { INSERT | UPDATE | DELETE }
This statement creates a new trigger. A trigger is a named
database object that is associated with a table, and that
activates when a particular event occurs for the table. The
trigger becomes associated with the table named
tbl_name, which must refer to a
permanent table. You cannot associate a trigger with a
TEMPORARY table or a view.
Trigger names exist in the schema namespace, meaning that all triggers must have unique names within a schema. Triggers in different schemas can have the same name.
This section describes CREATE
TRIGGER syntax. For additional discussion, see
Section 20.3.1, “Trigger Syntax and Examples”.
CREATE TRIGGER requires the
TRIGGER privilege for the table
associated with the trigger. The statement might also require the
SUPER privilege, depending on the
DEFINER value, as described later in this
section. If binary logging is enabled, CREATE
TRIGGER might require the
SUPER privilege, as described in
Section 20.7, “Binary Logging of Stored Programs”.
The DEFINER clause determines the security
context to be used when checking access privileges at trigger
activation time, as described later in this section.
trigger_time is the trigger action
time. It can be BEFORE or
AFTER to indicate that the trigger activates
before or after each row to be modified.
trigger_event indicates the kind of
operation that activates the trigger. These
trigger_event values are permitted:
INSERT: The trigger activates whenever a new row is inserted into the table; for example, throughINSERT,LOAD DATA, andREPLACEstatements.UPDATE: The trigger activates whenever a row is modified; for example, throughUPDATEstatements.DELETE: The trigger activates whenever a row is deleted from the table; for example, throughDELETEandREPLACEstatements.DROP TABLEandTRUNCATE TABLEstatements on the table do not activate this trigger, because they do not useDELETE. Dropping a partition does not activateDELETEtriggers, either.
The trigger_event does not represent a
literal type of SQL statement that activates the trigger so much
as it represents a type of table operation. For example, an
INSERT trigger activates not only
for INSERT statements but also
LOAD DATA statements because both
statements insert rows into a table.
A potentially confusing example of this is the INSERT
INTO ... ON DUPLICATE KEY UPDATE ... syntax: a
BEFORE INSERT trigger activates for every row,
followed by either an AFTER INSERT trigger or
both the BEFORE UPDATE and AFTER
UPDATE triggers, depending on whether there was a
duplicate key for the row.
Cascaded foreign key actions do not activate triggers.
There cannot be multiple triggers for a given table that have the
same trigger event and action time. For example, you cannot have
two BEFORE UPDATE triggers for a table. But you
can have a BEFORE UPDATE and a BEFORE
INSERT trigger, or a BEFORE UPDATE
and an AFTER UPDATE trigger.
trigger_body is the statement to
execute when the trigger activates. To execute multiple
statements, use the
BEGIN ... END
compound statement construct. This also enables you to use the
same statements that are permissible within stored routines. See
Section 13.6.1, “BEGIN ... END Compound-Statement Syntax”. Some statements are not permitted in
triggers; see Section C.1, “Restrictions on Stored Programs”.
Within the trigger body, you can refer to columns in the subject
table (the table associated with the trigger) by using the aliases
OLD and NEW.
OLD. refers
to a column of an existing row before it is updated or deleted.
col_nameNEW. refers
to the column of a new row to be inserted or an existing row after
it is updated.
col_name
MySQL stores the sql_mode system
variable setting in effect when a trigger is created, and always
executes the trigger body with this setting in force,
regardless of the current server SQL mode when the
trigger begins executing.
The DEFINER clause specifies the MySQL account
to be used when checking access privileges at trigger activation
time. If a user value is given, it
should be a MySQL account specified as
',
user_name'@'host_name'CURRENT_USER, or
CURRENT_USER(). The default
DEFINER value is the user who executes the
CREATE TRIGGER statement. This is
the same as specifying DEFINER = CURRENT_USER
explicitly.
If you specify the DEFINER clause, these rules
determine the valid DEFINER user values:
If you do not have the
SUPERprivilege, the only permitteduservalue is your own account, either specified literally or by usingCURRENT_USER. You cannot set the definer to some other account.If you have the
SUPERprivilege, you can specify any syntactically valid account name. If the account does not exist, a warning is generated.Although it is possible to create a trigger with a nonexistent
DEFINERaccount, it is not a good idea for such triggers to be activated until the account actually does exist. Otherwise, the behavior with respect to privilege checking is undefined.
MySQL takes the DEFINER user into account when
checking trigger privileges as follows:
At
CREATE TRIGGERtime, the user who issues the statement must have theTRIGGERprivilege.At trigger activation time, privileges are checked against the
DEFINERuser. This user must have these privileges:The
TRIGGERprivilege for the subject table.The
SELECTprivilege for the subject table if references to table columns occur usingOLD.orcol_nameNEW.in the trigger body.col_nameThe
UPDATEprivilege for the subject table if table columns are targets ofSET NEW.assignments in the trigger body.col_name=valueWhatever other privileges normally are required for the statements executed by the trigger.
For more information about trigger security, see Section 20.6, “Access Control for Stored Programs and Views”.
Within a trigger body, the
CURRENT_USER() function returns the
account used to check privileges at trigger activation time. This
is the DEFINER user, not the user whose actions
caused the trigger to be activated. For information about user
auditing within triggers, see
Section 6.3.9, “SQL-Based MySQL Account Activity Auditing”.
If you use LOCK TABLES to lock a
table that has triggers, the tables used within the trigger are
also locked, as described in
Section 13.3.5.2, “LOCK TABLES and Triggers”.
For additional discussion of trigger use, see Section 20.3.1, “Trigger Syntax and Examples”.
http://www.rustyrazorblade.com/index.php/2006/09/14/mysql-triggers-tutorial/
Use BEFORE triggers primarily for constraints or rules, not transactions, tweaking the NEW.* columns should be fine.
Stick with AFTER triggers for most other operations, such as inserting into a history table or updating a denormalization.
http://dev.mysql.com/doc/refman/5.0/en/secure-create-certs.html
...you can use Triggers and DES_ENCRYPT to move your password encryption to the database level and enforce it in a way that stops developers forgeting to use it (or bypassing it) with the following triggers...
CREATE TRIGGER user_insert BEFORE INSERT ON `user` FOR EACH ROW SET NEW.TimeStampCreated = NOW(), NEW.Password = DES_ENCRYPT(NEW.Password);
CREATE TRIGGER user_update BEFORE UPDATE ON `user` FOR EACH ROW SET NEW.Password = DES_ENCRYPT(NEW.Password);
...you'll also notice the first one enforces auditing in a way that saves you from relying on developers getting that right as well.
You could give your dev's a nice stored proc to retrieve or comapre their submitted password but hopefully they can remember either DES_ENCRYPT/_DECRYPT or your phone number ;^).
Whilst bearing in mind that this doesn't magically make your entire system "secure" by some magic wave of a wand, given that you've implemented SSL it should be trivial to secure the link between web and database server (if there even is a gap) and then you can use HTTPS and only a little more careful thought to implement a system that is secure from submission page through to backup system in such a way that only someone physically stood at the server with the server's and Mysql's root password could decrypt the password/data.
CREATE TRIGGER mytrigger BEFORE INSERT ON TABLE_1 FOR EACH ROW SET NEW.MY_DATETIME_COLUMN = NOW(), NEW.MY_DATE_COLUMN = CURDATE()
Note no END statement nor ending delimiter.
Luciano Fantuzzi suggested to cause a deliberate error; this might cause problems though.
It was my first approach too in a sanity-check like trigger. It calls a procedure which does the actual check and then assigns either 1 or 0 to @resultBool - 0 meaning it did not pass. In that case i wanted to prevent the INSERT by causing a deliberate error in the form of updating a non-existing table. This is what my attempt looked like:
CREATE TRIGGER sanityCheck
BEFORE INSERT ON someTable
FOR EACH ROW
BEGIN
CALL doSanityCheck(@resultBool, @resultMessage);
IF @resultBool = 0 THEN
UPDATE ThereWasAnError_Call_privilegeSanityCheck_ToViewTheError SET ThereWas='an error';
END IF;
END;//
While mysql allows the trigger even though the table doesn't exist, it will _always_ complain (throw an error) when it executes the trigger, even if @resultBool = 1. So, this will not work.
The suggestion of Nicolas LESCURE does work in combination with the IF-statement
My solution was to create a unique/primary key on the table I want to insert into (in this case on S_ID), then if my sanity check fails I change the s_id to 0. This method will only ever create one duff record with an s_id of 0. Obviously you need to INSERT ignore!
CREATE TRIGGER sanityCheck
BEFORE INSERT ON my_table
FOR EACH ROW
BEGIN
IF something THEN
SET NEW.S_ID = 0 ;
END IF;
END;
[http://www.php-trivandrum.org/code-snippets/invoke-shell-from-mysql-trigger.html Invoke shell from MySQL trigger]
http://www.php-trivandrum.org/code-snippets/invoke-shell-from-mysql-trigger/
-- pete
delimiter $$
DROP TABLE IF EXISTS blocked_insert_message $$
CREATE TABLE blocked_insert_message (
unique_error_msg VARCHAR(330) NOT NULL,
UNIQUE KEY `unique_error_msg` (`unique_error_msg`)
) $$
DROP PROCEDURE IF EXISTS die_with_error $$
CREATE PROCEDURE die_with_error(msg varchar(300))
COMMENT 'Call this to STOP ACTION with a message.'
MODIFIES SQL DATA BEGIN
DECLARE ts DATETIME DEFAULT NOW();
DECLARE txt VARCHAR(300) DEFAULT msg;
DECLARE uniq VARCHAR(330) DEFAULT (SELECT CONCAT(ts, ': ', txt));
-- Run it twice to throw as an error.
INSERT INTO blocked_insert_message VALUES (uniq);
INSERT INTO blocked_insert_message VALUES (uniq);
END $$
delimiter ;
When called from a trigger with "call die_with_error('test test test test');" the result is an error like this:
ERROR 1062 (23000) at line 1: Duplicate entry '2010-11-13 21:30:02: test test test test' for key 'unique_error_msg'
The clear benefit is that the error message will be thrown reliably and contain arbitrary (though short) free text.
delimiter //
use test//
create table trigger_test
(
id int not null
)//
drop trigger if exists trg_trigger_test_ins //
create trigger trg_trigger_test_ins before insert on trigger_test
for each row
begin
declare msg varchar(255);
if new.id < 0 then
set msg = concat('MyTriggerError: Trying to insert a negative value in trigger_test: ', cast(new.id as char));
signal sqlstate '45000' set message_text = msg;
end if;
end
//
delimiter ;
-- run the following as seperate statements:
insert into trigger_test values (1), (-1), (2); -- everything fails as one row is bad
select * from trigger_test;
insert into trigger_test values (1); -- succeeds as expected
insert into trigger_test values (-1); -- fails as expected
select * from trigger_test;