Using the OUTPUT Clause: A simple data archiving example

The OUTPUT Clause in T-SQL as described in MSDN SQL Server BOL, "returns information from, or expressions based on, each row affected by an INSERT, UPDATE, DELETE, or MERGE statement."

The functionality provided by the OUTPUT clause is very powerful and can be used in many scenarios. One such a scenario is Data Archiving.

Consider the following example based on which there is a "CustomerData" table containing customer IDs and status codes indidicating whether a customer is Active or Inactive.

A data archiving scenario would be to archive all the customers having the status "INACTIVE".

For this example I am going to use two tables called "CustomerData" and "CustomerArchive".

OK, let's see some code!



--Creates the schema
CREATE SCHEMA Test
GO


--Creates the data table for customers
CREATE TABLE Test.CustomerData
(
ID int IDENTITY(1,1) NOT NULL,
StatusCode VARCHAR(10) NOT NULL
)
GO


--Creates the data table for customers archive
CREATE TABLE Test.CustomerArchive
(
ID int NOT NULL,
StatusCode VARCHAR(10) NOT NULL
)
GO


--Populates data table with some sample data (Using Row Constructors)
INSERT INTO Test.CustomerData (StatusCode)
VALUES    ('ACTIVE'),
        ('ACTIVE'),
        ('INACTIVE'),
        ('ACTIVE'),
        ('ACTIVE'),
        ('INACTIVE'),
        ('ACTIVE'),
        ('INACTIVE'),
        ('ACTIVE'),
        ('ACTIVE')


Now, let's check out the contents of the two tables:


CustomerData















CustomerArchive





Now, let's archive the CustomersData table using the OUTPUT clause in the below query:

--Archive inactive customers and store the records in the "CustomerArchive" table
DELETE FROM Test.CustomerData
OUTPUT DELETED.* INTO Test.CustomerArchive
WHERE StatusCode='INACTIVE'


CustomerData













CustomerArchive







As you can see from the above results, with just a single T-SQL statement, we managed to delete the desired data from the CustomerData table and also archive it into the CustomerArchive table.

The above scenario was just a simple example on how data archiving can be performed using the OUTPUT clause in SQL Server. You can build more complex data archiving logic using the OUTPUT clause as you can also use the INSERTED keyword and perform multiple joins in the query which uses the OUTPUT clause.

Note: Always be careful when deleting data! Always keep a backup of your data.

Labels: , ,