Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Copying Table1 to Table2


Copying Table1 to Table2

Author
Message
monzulu
monzulu
Grasshopper
Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)

Group: General Forum Members
Points: 18 Visits: 60
hi guys,

can you give me some ideas how to do this? i have table1 and table2. i want to copy the contents of table1 to table2 and "prune" table1 with only 1 occurence of each place.


table1:

places
-----------
tokyo
manchester
new york
bangkok
tokyo
tokyo
tokyo
sydney
sydney
paris
paris
paris
paris
manchester
bangkok



table2:

places
--------
manchester
new york
bangkok
tokyo
sydney
paris



copy table1 to table2:

places
--------
manchester
new york
bangkok
tokyo
sydney
paris
tokyo
manchester
new york
bangkok
tokyo
tokyo
tokyo
sydney
sydney
paris
paris
paris
paris
manchester
bangkok


and "prune" table1 with only 1 occurance of each place:

table1:

places
-----------
tokyo
manchester
new york
bangkok
sydney
paris



thanks for any advice and suggestions.
Gianluca Sartori
Gianluca Sartori
SSCertifiable
SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)

Group: General Forum Members
Points: 6454 Visits: 13321
This should do the trick:

INSERT INTO Table2
SELECT DISTINCT Places
FROM Table1 AS A
WHERE NOT EXISTS (
SELECT 1
FROM Table2 AS B
WHERE A.Places = B.Places
)



--Gianluca Sartori

How to post T-SQL questions
spaghettidba.com
@spaghettidba
Suresh B.
Suresh B.
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1318 Visits: 5326
monzulu (6/24/2010)
i want to copy the contents of table1 to table2 and "prune" table1 with only 1 occurence of each place.
.....

thanks for any advice and suggestions.


SELECT ...UNION... also can be used to achieve this.
Cadavre
Cadavre
SSCrazy
SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)

Group: General Forum Members
Points: 2838 Visits: 8443
I read this question differently to the posters above me, so my solution is different.

From what I read, you want to copy the entire contents of table1 into table2, then go back to table1 and get rid of the duplicate data in there.

--First of all, we build our test environment
IF EXISTS (SELECT *
FROM sys.objects
WHERE object_id = Object_id(N'[dbo].[table1]')
AND TYPE IN ( N'U' ))
DROP TABLE [dbo].[table1]

CREATE TABLE [table1]
(
places VARCHAR(30)
)

INSERT INTO [table1]
SELECT 'tokyo'
UNION ALL SELECT 'manchester'
UNION ALL SELECT 'new york'
UNION ALL SELECT 'bangkok'
UNION ALL SELECT 'tokyo'
UNION ALL SELECT 'tokyo'
UNION ALL SELECT 'tokyo'
UNION ALL SELECT 'sydney'
UNION ALL SELECT 'sydney'
UNION ALL SELECT 'paris'
UNION ALL SELECT 'paris'
UNION ALL SELECT 'paris'
UNION ALL SELECT 'paris'
UNION ALL SELECT 'manchester'
UNION ALL SELECT 'bangkok'

IF EXISTS (SELECT *
FROM sys.objects
WHERE object_id = Object_id(N'[dbo].[table2]')
AND TYPE IN ( N'U' ))
DROP TABLE [dbo].[table2]

CREATE TABLE [table2]
(
places VARCHAR(30)
)

INSERT INTO [table2]
SELECT 'manchester'
UNION ALL SELECT 'new york'
UNION ALL SELECT 'bangkok'
UNION ALL SELECT 'tokyo'
UNION ALL SELECT 'sydney'
UNION ALL SELECT 'paris'



--Now we can look at your query
INSERT INTO [table2]
SELECT places
FROM [table1];

WITH cte (places, duplicatecount)
AS (SELECT places,
Row_number() OVER(PARTITION BY places ORDER BY places) AS
duplicatecount
FROM [table1])
DELETE FROM cte
WHERE duplicatecount > 1



SELECT *
FROM [table1]

SELECT *
FROM [table2]

DROP TABLE [table1]
DROP TABLE [table2]



/*OUTPUT

table 1
------------------------------
places
------------------------------
new york
bangkok
tokyo
sydney
paris
manchester


table2
------------------------------
places
------------------------------
manchester
new york
bangkok
tokyo
sydney
paris
tokyo
manchester
new york
bangkok
tokyo
tokyo
tokyo
sydney
sydney
paris
paris
paris
paris
manchester
bangkok
*/




Forever trying to learn

For better, quicker answers on T-SQL questions, click on the following...
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better, quicker answers on SQL Server performance related questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/



If you litter your database queries with nolock query hints, are you aware of the side effects?
Try reading a few of these links...

(*) Missing rows with nolock
(*) Allocation order scans with nolock
(*) Consistency issues with nolock
(*) Transient Corruption Errors in SQL Server error log caused by nolock
(*) Dirty reads, read errors, reading rows twice and missing rows with nolock


Craig Wilkinson - Software Engineer
LinkedIn
monzulu
monzulu
Grasshopper
Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)

Group: General Forum Members
Points: 18 Visits: 60
thanks guys for you inputs.

skcadavre thanks very much also. i'll give it a try. that looks like it's what i need.

have a nice day!
Eugene Elutin
Eugene Elutin
Hall of Fame
Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)

Group: General Forum Members
Points: 3394 Visits: 5478
Here is minimalist approach (use setup provided by skcadavre):



DELETE dbo.table1 OUTPUT deleted.places INTO dbo.table2 (places)

INSERT INTO dbo.table1 (places)
SELECT DISTINCT places FROM dbo.table2




There is a setback here: if, at the start, you would have some place in Table2 which is not in Table1, you will see it in Table1 as well after execution of this query...

_____________________________________________
"The only true wisdom is in knowing you know nothing"
"O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
(So many miracle inventions provided by MS to us...)

How to post your question to get the best and quick help
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search