Trigger
am 20.05.2007 04:55:20 von shane
I have been instructed to write a trigger that effectively acts as a foreign
key. The point (I think) is to get me used to writing triggers that dont
use the primary key(s)
I have created the following trigger
create trigger chk_team
on teams
for insert as
declare @chkCountry as char(2)
select @chkCountry = (select country from INSERTED)
-- if @@ROWCOUNT =0 RETURN
If @chkCountry NOT IN
(select distinct country from teams)
BEGIN
raiserror('Impossible country entered', 16, 1)
ROLLBACK TRANSACTION
END
However I tested it with the following insert statement
insert into teams values (15, 'London Paris', 'UK', 'Clive Woodward', 0,
NULL)
Which (unfortunately) works, IOW the above insert statement should cause the
error I specified as 'UK' does not exist in the set "select distinct
country from teams"
Any help appreciated
Re: Trigger
am 20.05.2007 05:16:28 von shane
Shane wrote:
> I have been instructed to write a trigger that effectively acts as a
> foreign
> key. The point (I think) is to get me used to writing triggers that dont
> use the primary key(s)
>
> I have created the following trigger
>
> create trigger chk_team
> on teams
> for insert as
> declare @chkCountry as char(2)
> select @chkCountry = (select country from INSERTED)
> -- if @@ROWCOUNT =0 RETURN
> If @chkCountry NOT IN
> (select distinct country from teams)
> BEGIN
> raiserror('Impossible country entered', 16, 1)
> ROLLBACK TRANSACTION
> END
>
> However I tested it with the following insert statement
>
> insert into teams values (15, 'London Paris', 'UK', 'Clive Woodward', 0,
> NULL)
>
> Which (unfortunately) works, IOW the above insert statement should cause
> the error I specified as 'UK' does not exist in the set "select distinct
> country from teams"
>
> Any help appreciated
I have got the triger working as I desire, however now I am perplexed as to
*why* it works..
The (new) trigger reads:
create trigger chk_team
on teams
for insert as
declare @chkCountry as char(2)
select @chkCountry = (select country from INSERTED)
-- if @@ROWCOUNT =0 RETURN
If @chkCountry IN
    (select distinct country from teams)
BEGIN
    raiserror('Impossible country entered', 16, 1)
    ROLLBACK TRANSACTION
END
I am now _seriously_ confused
--
Q: Who knows everything there is to be known about vector analysis?
A: The Oracle of del phi!
Re: Trigger
am 20.05.2007 05:40:02 von shane
Shane wrote:
> I am now _seriously_ confused
The trigger fires *after* an insert has taken place, therefore in the
second case the trigger rollsback because the country does now indeed exist
in the subquery
Any ideas?
--
Q: What does a mathematician present to his fiancée when he wants to
propose?
A: A polynomial ring!
Re: Trigger
am 20.05.2007 08:39:44 von Razvan Socol
Hello, Shane
When you write triggers, you should not assume that the INSERTED table
will always contain only one row.
Let's consider the following DDL and sample data:
CREATE TABLE Countries (
CountryCode char(2) PRIMARY KEY, --ISO 3166-1 alpha 2
CountryName varchar(50) UNIQUE
)
INSERT INTO Countries VALUES ('US','United States')
INSERT INTO Countries VALUES ('GB','United Kindom')
INSERT INTO Countries VALUES ('FR','France')
INSERT INTO Countries VALUES ('RO','Romania')
CREATE TABLE teams (
TeamName varchar(50) PRIMARY KEY,
CountryCode char(2) --REFERENCES Countries
)
I would write the following trigger:
CREATE TRIGGER teams_IU_CheckCountry ON teams
FOR INSERT, UPDATE
AS
IF @@ROWCOUNT>0 AND UPDATE(CountryCode) BEGIN
IF EXISTS (
SELECT * FROM inserted
WHERE CountryCode NOT IN (SELECT CountryCode FROM Countries)
) BEGIN
RAISERROR ('Incorrect country code !',16,1)
ROLLBACK
RETURN
END
END
We can check how it works using these statements:
INSERT INTO teams VALUES ('Chicago Bulls', 'US')
INSERT INTO teams VALUES ('Steaua Bucuresti', 'RO')
INSERT INTO teams SELECT Team, 'GB' FROM (
SELECT 'Manchester United' Team
UNION ALL SELECT 'Arsenal'
) x
INSERT INTO teams VALUES ('Juventus', 'IT')
--the last INSERT will fail because we have not entered the country
code for Italy
However, this trigger is not enough to ensure referential integrity,
we also need a trigger for the Countries table:
CREATE TRIGGER countries_UD_CheckTeams ON Countries
FOR UPDATE, DELETE
AS
IF @@ROWCOUNT>0 BEGIN
IF EXISTS (
SELECT * FROM teams
WHERE CountryCode IN (SELECT CountryCode FROM deleted)
AND CountryCode NOT IN (SELECT CountryCode FROM Countries)
) BEGIN
RAISERROR('This country code is used by a team !',16,1)
ROLLBACK
RETURN
END
END
GO
DELETE Countries WHERE CountryCode='FR'
-- works OK
DELETE Countries WHERE CountryCode='RO'
-- error, because we have a team
Of course, instead of using such triggers, it's much more prefferable
to have real foreign keys, because of performance reasons (both for
modifications and SELECT-s), ease of development (why write 20 lines
of code when you can write 2 words?), functionality (we can create a
cascading FK), etc.
Razvan
Re: Trigger
am 20.05.2007 19:05:31 von DA Morgan
Shane wrote:
> Shane wrote:
>
>> I am now _seriously_ confused
>
> The trigger fires *after* an insert has taken place, therefore in the
> second case the trigger rollsback because the country does now indeed exist
> in the subquery
>
> Any ideas?
That is one of the major problems with a product that only has AFTER
triggers. In those products that have both BEFORE and AFTER triggers,
AFTER triggers are used for auditing and BEFORE triggers used for
security and integrity. Essentially you are trying to do the right
thing, in the wrong way, in a product that truly doesn't support it.
Turn what you are doing into a multiuser environment with hundreds
or thousands of simultaneous users and it is a nightmare. Perhaps a
good learning experience ... but a nightmare.
--
Daniel A. Morgan
University of Washington
damorgan@x.washington.edu
(replace x with u to respond)
www.psoug.org
Re: Trigger
am 20.05.2007 19:50:15 von Erland Sommarskog
DA Morgan (damorgan@psoug.org) writes:
>> The trigger fires *after* an insert has taken place, therefore in the
>> second case the trigger rollsback because the country does now indeed
>> exist in the subquery
>>
>> Any ideas?
>
> That is one of the major problems with a product that only has AFTER
> triggers. In those products that have both BEFORE and AFTER triggers,
> AFTER triggers are used for auditing and BEFORE triggers used for
> security and integrity. Essentially you are trying to do the right
> thing, in the wrong way, in a product that truly doesn't support it.
Actually, SQL Server also has INSTEAD OF triggers, which is not really
the same thing as an BEFORE trigger. Since an INSTEAD OF trigger requires
you to redo the action that trigger it, it less apetizing for checks -
unless the check is of the kind "DELETE is not permitted on this table".
But a BEFORE trigger would not have help Shane, as his trigger seemed to
perform a check against existing data in the table. The logic appears
to be "it's OK to insert UK in the table if it's already there". His
AFTER trigger permits everything. But a BEFORE trigger would have kept
the table empty.
--
Erland Sommarskog, SQL Server MVP, esquel@sommarskog.se
Books Online for SQL Server 2005 at
http://www.microsoft.com/technet/prodtechnol/sql/2005/downlo ads/books.mspx
Books Online for SQL Server 2000 at
http://www.microsoft.com/sql/prodinfo/previousversions/books .mspx
Re: Trigger
am 20.05.2007 22:05:58 von shane
Erland Sommarskog wrote:
> DA Morgan (damorgan@psoug.org) writes:
>>> The trigger fires *after* an insert has taken place, therefore in the
>>> second case the trigger rollsback because the country does now indeed
>>> exist in the subquery
>>>
>>> Any ideas?
>>
>> That is one of the major problems with a product that only has AFTER
>> triggers. In those products that have both BEFORE and AFTER triggers,
>> AFTER triggers are used for auditing and BEFORE triggers used for
>> security and integrity. Essentially you are trying to do the right
>> thing, in the wrong way, in a product that truly doesn't support it.
>
> Actually, SQL Server also has INSTEAD OF triggers, which is not really
> the same thing as an BEFORE trigger. Since an INSTEAD OF trigger requires
> you to redo the action that trigger it, it less apetizing for checks -
> unless the check is of the kind "DELETE is not permitted on this table".
>
> But a BEFORE trigger would not have help Shane, as his trigger seemed to
> perform a check against existing data in the table. The logic appears
> to be "it's OK to insert UK in the table if it's already there". His
> AFTER trigger permits everything. But a BEFORE trigger would have kept
> the table empty.
>
>
>
>
Hi
Yes you are correct, my trigger would keep a new table empty, however this
trigger is being written for an existing table, that has existing entries.
I think the point of my trigger is supposed to keep the country list static.
I have used the following trigger, however I am not happy with it, as the
values are hard-coded.
create trigger chk_team
on teams
for insert as
declare @chkCountry as char(2)
select @chkCountry = (select country from INSERTED)
if @@ROWCOUNT =0 RETURN
If @chkCountry NOT IN ('NZ', 'AU', 'SA')
BEGIN
raiserror('Impossible country entered', 16, 1)
ROLLBACK TRANSACTION
END
--
Q: How can you tell that a mathematician is extroverted?
A: When talking to you, he looks at your shoes instead of at his.
Re: Trigger
am 21.05.2007 00:36:07 von Erland Sommarskog
Shane (shane@weasel.is-a-geek.net) writes:
> Yes you are correct, my trigger would keep a new table empty, however
> this trigger is being written for an existing table, that has existing
> entries. I think the point of my trigger is supposed to keep the country
> list static.
>
> I have used the following trigger, however I am not happy with it, as the
> values are hard-coded.
If there is a key in this table, then it is not that tricky:
CREATE TRIGGER no_more_teams ON tbl AFTER INSERT, UPDATE AS
IF EXISTS (SELECT *
FROM inserted i
WHERE NOT EXISTS (SELECT *
FROM tbl
WHERE tbl.teamid <> i.teamid
AND tbl.country = i.country))
BEGIN
ROLLBACK TRANSACTION
RAISERROR ('No more countries permitted!', 16, 1)
END
> create trigger chk_team
> on teams
> for insert as
> declare @chkCountry as char(2)
> select @chkCountry = (select country from INSERTED)
Again: you must not do this. A trigger must be able to handle the
situation more than one row is inserted, so you cannot select into
a variable.
....Wait! Slap me on the face! The trigger above will also not handle
multi-row inserts correctly, but may permit new countries in this case.
OK, so it is a bit more tricker. What about:
IF EXISTS (SELECT *
FROM (SELECT country, COUNT(*) AS cnt
FROM inserted
GROUP BY country) AS i
JOIN (SELECT country, COUNT(*) AS cnt
FROM tbl
GROUP BY country) AS t ON t.country = i.country
WHERE t.cnt = i.cnt)
BEGIN
ROLLBACK TRANSACTION
RAISERROR ('No more countries permitted!', 16, 1)
END
Or write an INSTEAD OF trigger, in which case your original logic
will work. But you still need to handle multi-row inserts.)
--
Erland Sommarskog, SQL Server MVP, esquel@sommarskog.se
Books Online for SQL Server 2005 at
http://www.microsoft.com/technet/prodtechnol/sql/2005/downlo ads/books.mspx
Books Online for SQL Server 2000 at
http://www.microsoft.com/sql/prodinfo/previousversions/books .mspx