By using this site, you agree to our updated Privacy Policy and our Terms of Use. Manage your Cookies Settings.
443,665 Members | 1,251 Online
Bytes IT Community
+ Ask a Question
Need help? Post your question and get tips & solutions from a community of 443,665 IT Pros & Developers. It's quick & easy.

SQL Trigger for changed columns?

P: n/a
I have never written a trigger before and now am seeing the light. Is
there a way to write a trigger so that if a user changes any column in
a single row on one table then the trigger will write the value of
this (these) rows to a second table. I don't want the unchanged
columns, just the changed columns (with column names...)
Thanks,
lq
Jul 20 '05 #1
Share this Question
Share on Google+
10 Replies


P: n/a
On 12 Apr 2004 18:36:24 -0700, Lauren Quantrell wrote:
I have never written a trigger before and now am seeing the light. Is
there a way to write a trigger so that if a user changes any column in
a single row on one table then the trigger will write the value of
this (these) rows to a second table. I don't want the unchanged
columns, just the changed columns (with column names...)
Thanks,
lq


Something like this, maybe?

CREATE TABLE Lauren
(KeyCol int not null primary key,
DataCol1 int not null,
DataCol2 int null,
DataCol3 int not null)
go
CREATE TABLE Quantrell
(KeyCol int not null primary key,
ColName char(8) not null,
NewData int not null)
go

CREATE TRIGGER LaurenQuantrell
ON Lauren AFTER UPDATE
AS
IF UPDATE(KeyCol)
BEGIN
RAISERROR ('Don't change the key column!!', 16, 1)
ROLLBACK TRANSACTION
RETURN
END

INSERT Quantrell (KeyCol, ColName, NewData)
SELECT inserted.KeyCol, 'DataCol1', inserted.DataCol1
FROM inserted
INNER JOIN deleted ON deleted.KeyCol = inserted.KeyCol
WHERE inserted.DataCol1 <> deleted.DataCol1

INSERT Quantrell (KeyCol, ColName, NewData)
SELECT inserted.KeyCol, 'DataCol2', inserted.DataCol1
FROM inserted
INNER JOIN deleted ON deleted.KeyCol = inserted.KeyCol
WHERE inserted.DataCol2 <> deleted.DataCol2
OR (inserted.DataCol2 IS NULL AND deleted.DataCol2 IS NOT NULL)
OR (inserted.DataCol2 IS NOT NULL AND deleted.DataCol2 IS NULL)

INSERT Quantrell (KeyCol, ColName, NewData)
SELECT inserted.KeyCol, 'DataCol3', inserted.DataCol3
FROM inserted
INNER JOIN deleted ON deleted.KeyCol = inserted.KeyCol
WHERE inserted.DataCol3 <> deleted.DataCol3
go
Best, Hugo
--

(Remove _NO_ and _SPAM_ to get my e-mail address)
Jul 20 '05 #2

P: n/a
On 12 Apr 2004 18:36:24 -0700, Lauren Quantrell wrote:
I have never written a trigger before and now am seeing the light. Is
there a way to write a trigger so that if a user changes any column in
a single row on one table then the trigger will write the value of
this (these) rows to a second table. I don't want the unchanged
columns, just the changed columns (with column names...)
Thanks,
lq


Something like this, maybe?

CREATE TABLE Lauren
(KeyCol int not null primary key,
DataCol1 int not null,
DataCol2 int null,
DataCol3 int not null)
go
CREATE TABLE Quantrell
(KeyCol int not null primary key,
ColName char(8) not null,
NewData int not null)
go

CREATE TRIGGER LaurenQuantrell
ON Lauren AFTER UPDATE
AS
IF UPDATE(KeyCol)
BEGIN
RAISERROR ('Don't change the key column!!', 16, 1)
ROLLBACK TRANSACTION
RETURN
END

INSERT Quantrell (KeyCol, ColName, NewData)
SELECT inserted.KeyCol, 'DataCol1', inserted.DataCol1
FROM inserted
INNER JOIN deleted ON deleted.KeyCol = inserted.KeyCol
WHERE inserted.DataCol1 <> deleted.DataCol1

INSERT Quantrell (KeyCol, ColName, NewData)
SELECT inserted.KeyCol, 'DataCol2', inserted.DataCol1
FROM inserted
INNER JOIN deleted ON deleted.KeyCol = inserted.KeyCol
WHERE inserted.DataCol2 <> deleted.DataCol2
OR (inserted.DataCol2 IS NULL AND deleted.DataCol2 IS NOT NULL)
OR (inserted.DataCol2 IS NOT NULL AND deleted.DataCol2 IS NULL)

INSERT Quantrell (KeyCol, ColName, NewData)
SELECT inserted.KeyCol, 'DataCol3', inserted.DataCol3
FROM inserted
INNER JOIN deleted ON deleted.KeyCol = inserted.KeyCol
WHERE inserted.DataCol3 <> deleted.DataCol3
go
Best, Hugo
--

(Remove _NO_ and _SPAM_ to get my e-mail address)
Jul 20 '05 #3

P: n/a
Hugo,
Thanks for that code!
Now, the rub is that all the columns are integer types. I've got
ntext, nvarchar, int, smallint, tinyint...
lq

Hugo Kornelis <hugo@pe_NO_rFact.in_SPAM_fo> wrote in message news:<e6********************************@4ax.com>. ..
On 12 Apr 2004 18:36:24 -0700, Lauren Quantrell wrote:
I have never written a trigger before and now am seeing the light. Is
there a way to write a trigger so that if a user changes any column in
a single row on one table then the trigger will write the value of
this (these) rows to a second table. I don't want the unchanged
columns, just the changed columns (with column names...)
Thanks,
lq


Something like this, maybe?

CREATE TABLE Lauren
(KeyCol int not null primary key,
DataCol1 int not null,
DataCol2 int null,
DataCol3 int not null)
go
CREATE TABLE Quantrell
(KeyCol int not null primary key,
ColName char(8) not null,
NewData int not null)
go

CREATE TRIGGER LaurenQuantrell
ON Lauren AFTER UPDATE
AS
IF UPDATE(KeyCol)
BEGIN
RAISERROR ('Don't change the key column!!', 16, 1)
ROLLBACK TRANSACTION
RETURN
END

INSERT Quantrell (KeyCol, ColName, NewData)
SELECT inserted.KeyCol, 'DataCol1', inserted.DataCol1
FROM inserted
INNER JOIN deleted ON deleted.KeyCol = inserted.KeyCol
WHERE inserted.DataCol1 <> deleted.DataCol1

INSERT Quantrell (KeyCol, ColName, NewData)
SELECT inserted.KeyCol, 'DataCol2', inserted.DataCol1
FROM inserted
INNER JOIN deleted ON deleted.KeyCol = inserted.KeyCol
WHERE inserted.DataCol2 <> deleted.DataCol2
OR (inserted.DataCol2 IS NULL AND deleted.DataCol2 IS NOT NULL)
OR (inserted.DataCol2 IS NOT NULL AND deleted.DataCol2 IS NULL)

INSERT Quantrell (KeyCol, ColName, NewData)
SELECT inserted.KeyCol, 'DataCol3', inserted.DataCol3
FROM inserted
INNER JOIN deleted ON deleted.KeyCol = inserted.KeyCol
WHERE inserted.DataCol3 <> deleted.DataCol3
go
Best, Hugo

Jul 20 '05 #4

P: n/a
On 14 Apr 2004 16:13:37 -0700, Lauren Quantrell wrote:
Hugo,
Thanks for that code!
Now, the rub is that all the columns are integer types. I've got
ntext, nvarchar, int, smallint, tinyint...
lq


Hi Lauren,

If you need the data in the second table for audit purposes, then this
might be one of the very rare cases where datatype sql_variant can be
used. Check Books Online for details on this datatype and see if it
can be used in your situation.

I the second table is not for audit, then it might well be worth to
consider the design of this table. If you can explain what business
problem you have to solve, I can try if I can find a better solution.

Best, Hugo
--

(Remove _NO_ and _SPAM_ to get my e-mail address)
Jul 20 '05 #5

P: n/a
Hugo,
Thanks for that code!
Now, the rub is that all the columns are integer types. I've got
ntext, nvarchar, int, smallint, tinyint...
lq

Hugo Kornelis <hugo@pe_NO_rFact.in_SPAM_fo> wrote in message news:<e6********************************@4ax.com>. ..
On 12 Apr 2004 18:36:24 -0700, Lauren Quantrell wrote:
I have never written a trigger before and now am seeing the light. Is
there a way to write a trigger so that if a user changes any column in
a single row on one table then the trigger will write the value of
this (these) rows to a second table. I don't want the unchanged
columns, just the changed columns (with column names...)
Thanks,
lq


Something like this, maybe?

CREATE TABLE Lauren
(KeyCol int not null primary key,
DataCol1 int not null,
DataCol2 int null,
DataCol3 int not null)
go
CREATE TABLE Quantrell
(KeyCol int not null primary key,
ColName char(8) not null,
NewData int not null)
go

CREATE TRIGGER LaurenQuantrell
ON Lauren AFTER UPDATE
AS
IF UPDATE(KeyCol)
BEGIN
RAISERROR ('Don't change the key column!!', 16, 1)
ROLLBACK TRANSACTION
RETURN
END

INSERT Quantrell (KeyCol, ColName, NewData)
SELECT inserted.KeyCol, 'DataCol1', inserted.DataCol1
FROM inserted
INNER JOIN deleted ON deleted.KeyCol = inserted.KeyCol
WHERE inserted.DataCol1 <> deleted.DataCol1

INSERT Quantrell (KeyCol, ColName, NewData)
SELECT inserted.KeyCol, 'DataCol2', inserted.DataCol1
FROM inserted
INNER JOIN deleted ON deleted.KeyCol = inserted.KeyCol
WHERE inserted.DataCol2 <> deleted.DataCol2
OR (inserted.DataCol2 IS NULL AND deleted.DataCol2 IS NOT NULL)
OR (inserted.DataCol2 IS NOT NULL AND deleted.DataCol2 IS NULL)

INSERT Quantrell (KeyCol, ColName, NewData)
SELECT inserted.KeyCol, 'DataCol3', inserted.DataCol3
FROM inserted
INNER JOIN deleted ON deleted.KeyCol = inserted.KeyCol
WHERE inserted.DataCol3 <> deleted.DataCol3
go
Best, Hugo

Jul 20 '05 #6

P: n/a
On 14 Apr 2004 16:13:37 -0700, Lauren Quantrell wrote:
Hugo,
Thanks for that code!
Now, the rub is that all the columns are integer types. I've got
ntext, nvarchar, int, smallint, tinyint...
lq


Hi Lauren,

If you need the data in the second table for audit purposes, then this
might be one of the very rare cases where datatype sql_variant can be
used. Check Books Online for details on this datatype and see if it
can be used in your situation.

I the second table is not for audit, then it might well be worth to
consider the design of this table. If you can explain what business
problem you have to solve, I can try if I can find a better solution.

Best, Hugo
--

(Remove _NO_ and _SPAM_ to get my e-mail address)
Jul 20 '05 #7

P: n/a
Hugo,
Thanks for your replies and your help.
I'm trying to keep a record of every change a user makes to any field
on a form.
The underlying recordsource is an SP that refers to a single table.
The user can only modify one row at a time.

Ideally, I would track changes to datetime, int, nvarchar and ntext
columns.
This is used entirely as an audit trail, but users would be able to
click a button to view the changes any user had made.

The table holding the audit would need a column for the fieldname
nvarchar(25), databeforechange (?), dataafterchange (?), userID int,
dateofchange smalldatetime.

This must be a pretty common need?

lq

Hugo Kornelis <hugo@pe_NO_rFact.in_SPAM_fo> wrote in message news:<pn********************************@4ax.com>. ..
On 14 Apr 2004 16:13:37 -0700, Lauren Quantrell wrote:
Hugo,
Thanks for that code!
Now, the rub is that all the columns are integer types. I've got
ntext, nvarchar, int, smallint, tinyint...
lq


Hi Lauren,

If you need the data in the second table for audit purposes, then this
might be one of the very rare cases where datatype sql_variant can be
used. Check Books Online for details on this datatype and see if it
can be used in your situation.

I the second table is not for audit, then it might well be worth to
consider the design of this table. If you can explain what business
problem you have to solve, I can try if I can find a better solution.

Best, Hugo

Jul 20 '05 #8

P: n/a
On 15 Apr 2004 15:49:24 -0700, Lauren Quantrell wrote:
Hugo,
Thanks for your replies and your help.
I'm trying to keep a record of every change a user makes to any field
on a form.
The underlying recordsource is an SP that refers to a single table.
The user can only modify one row at a time.

Ideally, I would track changes to datetime, int, nvarchar and ntext
columns.
This is used entirely as an audit trail, but users would be able to
click a button to view the changes any user had made.

The table holding the audit would need a column for the fieldname
nvarchar(25), databeforechange (?), dataafterchange (?), userID int,
dateofchange smalldatetime.

This must be a pretty common need?

lq


Hi Lauren,

The need is pretty common indeed. But you have chosen an approach that
differs from how I normally solve this.

I prefer to make an audit table with the same rows as the actual data
table (but all except the key columns nullable), plus extra rows (not
nullable) for userid, time of change, etc. PK of this table is equal
to the PK of the actual data table plus time of change.

Then, I make the following triggers:
* One trigger for insert, update that enters all "new" information
(from the inserted pseudo-table) into the audit table
* One trigger for delete that enters just the key columns into the
audit table. If all non-key columns in the actual data table are
nullable, you'll also need a "deleted" indication to see the
difference between a deletion and an update that sets all non-key
columns to null.

Advantage of this approach is that you have all information at a
glance, the triggers are easy to set up and will also work when
set-based changes are carried out on the data and it saves some space
if changes usually affect multiple columns at the same time.

Disadvantage is that your approach costs less space if changes usually
affect only one or two columns. That being said, I'd still choose "my"
approach even if it costs more disk space - I value ease of use and
maintainability more than disk space.

(Note - the ntext columns might require special handling, in both
scenario's. In "your" version because a sql_variant datatype can't be
used to hold ntext (if I recall correctly); in "my" version because it
might be worthwile to exclude this column from the audit table if the
text is rarely changed. Besides, I don't know how ntext data is
handled in triggers and if all set-based operations are allowed on
ntext data)

Best, Hugo
--

(Remove _NO_ and _SPAM_ to get my e-mail address)
Jul 20 '05 #9

P: n/a
Hugo,
Thanks for your replies and your help.
I'm trying to keep a record of every change a user makes to any field
on a form.
The underlying recordsource is an SP that refers to a single table.
The user can only modify one row at a time.

Ideally, I would track changes to datetime, int, nvarchar and ntext
columns.
This is used entirely as an audit trail, but users would be able to
click a button to view the changes any user had made.

The table holding the audit would need a column for the fieldname
nvarchar(25), databeforechange (?), dataafterchange (?), userID int,
dateofchange smalldatetime.

This must be a pretty common need?

lq

Hugo Kornelis <hugo@pe_NO_rFact.in_SPAM_fo> wrote in message news:<pn********************************@4ax.com>. ..
On 14 Apr 2004 16:13:37 -0700, Lauren Quantrell wrote:
Hugo,
Thanks for that code!
Now, the rub is that all the columns are integer types. I've got
ntext, nvarchar, int, smallint, tinyint...
lq


Hi Lauren,

If you need the data in the second table for audit purposes, then this
might be one of the very rare cases where datatype sql_variant can be
used. Check Books Online for details on this datatype and see if it
can be used in your situation.

I the second table is not for audit, then it might well be worth to
consider the design of this table. If you can explain what business
problem you have to solve, I can try if I can find a better solution.

Best, Hugo

Jul 20 '05 #10

P: n/a
On 15 Apr 2004 15:49:24 -0700, Lauren Quantrell wrote:
Hugo,
Thanks for your replies and your help.
I'm trying to keep a record of every change a user makes to any field
on a form.
The underlying recordsource is an SP that refers to a single table.
The user can only modify one row at a time.

Ideally, I would track changes to datetime, int, nvarchar and ntext
columns.
This is used entirely as an audit trail, but users would be able to
click a button to view the changes any user had made.

The table holding the audit would need a column for the fieldname
nvarchar(25), databeforechange (?), dataafterchange (?), userID int,
dateofchange smalldatetime.

This must be a pretty common need?

lq


Hi Lauren,

The need is pretty common indeed. But you have chosen an approach that
differs from how I normally solve this.

I prefer to make an audit table with the same rows as the actual data
table (but all except the key columns nullable), plus extra rows (not
nullable) for userid, time of change, etc. PK of this table is equal
to the PK of the actual data table plus time of change.

Then, I make the following triggers:
* One trigger for insert, update that enters all "new" information
(from the inserted pseudo-table) into the audit table
* One trigger for delete that enters just the key columns into the
audit table. If all non-key columns in the actual data table are
nullable, you'll also need a "deleted" indication to see the
difference between a deletion and an update that sets all non-key
columns to null.

Advantage of this approach is that you have all information at a
glance, the triggers are easy to set up and will also work when
set-based changes are carried out on the data and it saves some space
if changes usually affect multiple columns at the same time.

Disadvantage is that your approach costs less space if changes usually
affect only one or two columns. That being said, I'd still choose "my"
approach even if it costs more disk space - I value ease of use and
maintainability more than disk space.

(Note - the ntext columns might require special handling, in both
scenario's. In "your" version because a sql_variant datatype can't be
used to hold ntext (if I recall correctly); in "my" version because it
might be worthwile to exclude this column from the audit table if the
text is rarely changed. Besides, I don't know how ntext data is
handled in triggers and if all set-based operations are allowed on
ntext data)

Best, Hugo
--

(Remove _NO_ and _SPAM_ to get my e-mail address)
Jul 20 '05 #11

This discussion thread is closed

Replies have been disabled for this discussion.