560 attributed reviews in the last 3 years
Refreshingly small course sizes
Outstandingly good courseware
Whizzy online classrooms
Wise Owls only (no freelancers)
Almost no cancellations
We have genuine integrity
We invoice after training
Review 30+ years of Wise Owl
View our top 100 clients
Search our website
We also send out useful tips in a monthly email newsletter ...
Using SELECT INTO and INSERT to insert SQL rows Part three of a four-part series of blogs |
---|
There are various ways to insert data into new or existing tables in T-SQL - this blog gives examples of each.
This blog is part of a full online tutorial in SQL. Please have a look too at our introductory and advanced SQL training courses for businesses like yours.
|
Instead of inserting rows one at a time, you can take the set of rows returned by a SELECT statement and add these at the bottom of an existing table, using:
The only rule is that the fields you're inserting must be of the same data type as the fields you're inserting into.
To show how this works, let's set up two similar tables to hold names of authors (notice that the number, order and names of the columns aren't identical). First a table to hold the source authors:
CREATE TABLE tblAuthor (
AuthorId int IDENTITY(1,1) PRIMARY KEY,
Rating int,
FirstName varchar(100),
LastName varchar(100) NOT NULL,
)
Now we'll add in 3 authors:
INSERT INTO tblAuthor (Rating, FirstName, LastName)
VALUES (10, 'John', 'Wyndham')
INSERT INTO tblAuthor (Rating, FirstName, LastName)
VALUES (8, 'Vikram', 'Seth')
INSERT INTO tblAuthor (Rating, FirstName, LastName)
VALUES (3, 'Cathy', 'Cassidy')
The table we'll insert rows into will have Surname, FirstName and Genre fields:
CREATE TABLE tblAuthorTarget (
Surname varchar(100),
FirstName varchar(100),
Genre varchar(100)
)
To insert into the target table those authors whose surnames contain a Y, first write and test the SELECT statement:
SELECT
FirstName,
LastName
FROM
tblAuthor
WHERE
-- show authors with a Y in name
LastName like '%y%'
This will return the following 2 rows:
The rows returned by this SELECT statement.
To put these rows in our target table, just add an INSERT INTO statement above it:
-- add rows into target table
INSERT INTO tblAuthorTarget (
FirstName,
Surname
)
-- rows to be added
SELECT
FirstName,
LastName
FROM
tblAuthor
WHERE
LastName like '%y%'
-- test results
SELECT * FROM tblAuthorTarget
This query will show the 2 rows added into the target table:
Notice that the column headings are different from those in the source table.
To understand this statement, remember that SQL always works with sets of rows. So the command reads: take this set of rows and put them in another table.
You can take the results from a stored procedure and feed them into another table. For example, suppose we create a stored procedure to list out the authors in the source table whose names contain a given letter:
CREATE PROC spListAuthors(
@Letter char(1)
)
AS
-- show authors whose names contain a given letter
SELECT
FirstName,
LastName
FROM
tblAuthor
WHERE
LastName like '%' + @Letter + '%'
You could then call this stored procedure when inserting rows into a table:
-- add rows into target table
INSERT INTO tblAuthorTarget (
FirstName,
Surname
)
-- return rows from stored procedure
EXEC spListAuthors 'H'
-- test results
SELECT * FROM tblAuthorTarget
This will show the authors whose names contain an H:
The rows returned by this excerpt of SQL.
Using a stored procedure like this can make this command easier to read, since it separates the selection of data from the insertion into a new table.
A neat trick in SQL allows you to show selected fields from the rows inserted, using the OUTPUT keyword with Inserted. The following SQL uses UNION ALL to add 3 rows into a new table of authors:
-- create table of authors
CREATE TABLE tblAuthor (
AuthorId int IDENTITY(1,1) PRIMARY KEY,
FirstName varchar(100),
LastName varchar(100) NOT NULL,
)
-- add in 3 authors
INSERT INTO tblAuthor(
FirstName,
LastName
)
-- list out selected columns added
OUTPUT
Inserted.AuthorId,
Inserted.FirstName,
Inserted.LastName
SELECT 'Vikram', 'Seth'
UNION ALL
SELECT 'Ian', 'Banks'
UNION ALL
SELECT 'Robert', 'Harris'
UNION ALL
SELECT 'George', 'Orwell'
Notice that we output the author's id, first name and surname for each author added:
-- list out selected columns added
OUTPUT
Inserted.AuthorId,
Inserted.FirstName,
Inserted.LastName
Here's what the above SQL would show:
We've chosen to output the author id, first name and last name for each row added.
All of the examples on this page add rows into an existing table, but what if you want to create a new one? That's the subject for the final part of this tutorial.
Parts of this blog |
---|
|
Some other pages relevant to the above blogs include:
Kingsmoor House
Railway Street
GLOSSOP
SK13 2AA
Landmark Offices
99 Bishopsgate
LONDON
EC2M 3XD
Holiday Inn
25 Aytoun Street
MANCHESTER
M1 3AE
© Wise Owl Business Solutions Ltd 2023. All Rights Reserved.