SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


remove rows from staging table that are duplicated before insert the data into the database normal...


remove rows from staging table that are duplicated before insert the data into the database normal tables

Author
Message
river1
river1
SSCrazy
SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)

Group: General Forum Members
Points: 2302 Visits: 1366
Hi,

I have this table:

CREATE TABLE [dbo].[BULK_ACTIVIDADES](
[CODCTB] [bigint] NULL,
[NIF_ANTIGO] [varchar](20) NOT NULL,
[NIF] [varchar](20) NULL,
[FILIAL_NUMBER] [varchar](20) NULL,
[INDEX_POS] [int] NULL,
[DESC_ACTIVIDADE] [varchar](100) NULL
) ON [PRIMARY]

GO
SET ANSI_PADDING OFF


I want to delete the duplicated rows.

I could do something like:


select * into bulk_actividades1
from
(select * from bulk_actividades
union
select * from bulk_actividades) r

truncate table bulk_actividades
drop table bulk_actividades

select * into bulk_actividades from bulk_actvidades1

truncate bulk_actividades1
drop table bulk_actvidades1


But this table and other have a lot of rows (3 million) so I ask. Do you SQL Server experts know a faster way of doing this in t-sql?

thank you.
Jack Corbett
  Jack Corbett
SSC-Insane
SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)

Group: General Forum Members
Points: 23826 Visits: 14905
One thing you could do is just use a SELECT DISTINCT when transferring the data, but if you want to remove duplicates I'd suggest this:


WITH deDupe
AS (
SELECT
BA.CODCTB,
BA.NIF_ANTIGO,
BA.NIF,
BA.FILIAL_NUMBER,
BA.INDEX_POS,
BA.DESC_ACTIVIDADE,
ROW_NUMBER() OVER (PARTITION BY BA.CODCTB, BA.NIF_ANTIGO,
BA.NIF, BA.FILIAL_NUMBER, BA.INDEX_POS,
BA.DESC_ACTIVIDADE ORDER BY BA.CODCTB) AS RowNo
FROM
dbo.BULK_ACTIVIDADES AS BA
)
DELETE FROM
deDupe
WHERE
deDupe.RowNo > 1





Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work

Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
river1
river1
SSCrazy
SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)

Group: General Forum Members
Points: 2302 Visits: 1366
Is that faster than my exemple?
Jack Corbett
  Jack Corbett
SSC-Insane
SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)

Group: General Forum Members
Points: 23826 Visits: 14905
I believe the pattern I have proposed will outperform the pattern you have proposed. My proposal only makes one pass at the data while yours makes multiple passes and multiple copies so much more write activity in particular.



Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work

Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
river1
river1
SSCrazy
SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)

Group: General Forum Members
Points: 2302 Visits: 1366
understood. I will test it.

Thank you.
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