Written by Ian Treasure
Gethyn recently posted on deleting from a view. He used a common situation where several tables are joined into one view. In simpler situations, views can be updated directly. If required, triggers can be used to allow updates to views which join several tables. This post will consider updates to simple views and the use of triggers. It does not consider partitioned updatable views, which are usually used for load balancing. As an alternative to these views partitioned tables should be considered.
First – updating a simple view. Create a base table – call it Employee, with a column to show holidays, in hours. We will then insert a test row
create table Employee
(EmployeeID int,
EmployeeName varchar(30),
Employeecode varchar(30),
MaritalStatus bit,
HolidayHours int)
go
INSERT Employee(EmployeeID, EmployeeName, Employeecode, MaritalStatus,HolidayHours)
Values (1,'Smith','WR 56 rf 67', '0',160)
Now we create a view, which calculates a column – number of days leave – based on the number of hours in the employee table. There are eight hours per day.
Create view vwEmployees
AS
SELECT
EmployeeId, EmployeeName,
HolidayHours / 8 As [HolidayDays]
FROM Employee
Now update the view, and change the employee name. This works – there is only one table, and the column exists in both the view and the base table.
update vwEmployees set EmployeeName = 'Jones'
where EmployeeID = 1
Now try to update the view, but this time change the [HolidayDays] column
update vwEmployees set HolidayDays = 45
where EmployeeID = 1
As you would expect, this fails with a message:
Msg 4406, Level 16, State 1, Line 2
Update or insert of view or function 'vwEmployees' failed because it contains a derived or constant field.
This is because there is no storage associated with this column – it is calculated when the view is executed. I will take this further below.
Finally, try the delete command-
delete vwEmployees
Again, this command works OK – you have deleted the row that you created above.
Now, make the [HolidayDays} computed column on the view updateable. Insert a single row of data to the Employee table, and create a trigger as follows:
INSERT Employee(EmployeeID, EmployeeName, Employeecode, MaritalStatus,HolidayHours)
Values (1,'Smith','WR 56 rf 67', '0',160)
CREATE TRIGGER trg_VWEmployees ON VWEmployees
INSTEAD OF UPDATE
AS
BEGIN
UPDATE Employee
SET EmployeeName = inserted.employeeName,
HolidayHours = inserted.HolidayDays * 8
FROM inserted
WHERE
Employee.EmployeeId = inserted.EmployeeID
END
GO
The following update will now succeed, and sets the HolidayHours column on the Employee table to 168.
update vwEmployees set HolidayDays = 21
where EmployeeID = 1
This approach will also work if you attempt to update a view with several tables joined together. Create an INSTEAD OF trigger and update the individual tables in the trigger.
This approach is potentially useful because it hides details of the application from the user. In this simple example, the application holds leave as hours, but the user may think in terms of days. By creating a view which the user can update, it is possible to hide complexities of the application from the user. The user does not need to understand ho the database is implemented – the view and the trigger reflects the users image of the data.