Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

Repopulating a sequenced column that has gone out of sequence. Expand / Collapse
Author
Message
Posted Saturday, July 5, 2014 8:53 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, July 18, 2014 11:33 PM
Points: 166, Visits: 484
We have an application which has had a big design floor and is now causing an issue which needs to be rectified.
It inserted data in batches of 2000 rows which should have always been in sequence. A column was used which recorded an ever increasing numerical value for each row that was inserted. So batch 1 would have a start value of 1 and an end value of 2001. Batch 2 would have a start value of 2002 and an end value of 4002 etc.

The problem is the application which inserted these records in order, missed some records. So in actual fact we have:
Batch 1 = seq 1 - 2001 (total 2000)
Batch 2 = seq 2002 - 3998 (total 1996, 4 missing)
batch 3 = seq 3999 - 5999 (total 2000)

Now the missing data has been found, it will be inserted at the end of the table, as we cannot insert it where its should be as the sequence value has been used by the next batch already. Lets say the table is 10,000 rows so far, so the seq for batch 2, for example, will be 2002-3998, then after the missing data is inserted, 10,001 - 10,005. The application uses these sequences to show the range of data so where it should be 2000 rows being returned, it would now show 8003 rows - all the other batches between the first and last sequences for the batch!

I need to change the sequence values across the whole table so they are in order. I can select the data in the correct sort order as there is another unique key on the table, but unsure how best to use this to change the sequence column to be in order for all rows.
Adding an identity column would work and then remove and rename the seq column, but I obviously cannot add this based on another columns sort order. The identity column would use the clustered key which is in the incorrect order!!

I would be interested if anyone can think of an approach to sort this mess out and I be very grateful.

Thanks.


Post #1589511
Posted Saturday, July 5, 2014 9:53 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 5:09 PM
Points: 23,089, Visits: 31,635
Hard to say with what you posted but looks doable. If you post the DDL for the table, some sample data (as INSERT statements), and the expected results I am sure we could show you how to do it easily since it sounds like all the info we need exists in the data (just be sure to show us the pertinent data elements).


Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1589526
Posted Saturday, July 5, 2014 10:09 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, July 18, 2014 11:33 PM
Points: 166, Visits: 484
Thanks. Picture speaks a thousand words. So


--Example table
create table Labels
(Id int identity (1,1),
Value varchar(20),
IntSequence bigint,
ExternalSequence bigint,
BatchId int)

-- Insert some data

Insert into labels
(Value, IntSequence, ExternalSequence, BatchId)
Values
--batch 1
('exampleValue', 1,1,1),
('exampleValue', 2,2,1),
('exampleValue', 3,3,1),
--batch 2
('exampleValue', 4,6,2),
('exampleValue', 5,7,2),
('exampleValue', 6,8,2),
-- batch 3
('exampleValue', 7,10,3),
('exampleValue', 8,11,3),
-- Insert the missing values for batch 1
('exampleValue', 9,4,1),
('exampleValue', 10,5,1),
-- insert the missing values for batch 2
('exampleValue', 11,9,2)

select * from Labels -- Current order showing external seq in wrong order, but internal seq in correct order.
Select * from labels order by ExternalSequence asc -- Order by the other column which is in correct order shows true order, but internal sequence in wrong order

Hopefully the above code helps. I need to get the internal sequence to be in the sequential order dependant on the external sequence. My real problem is like the above, but unfortunately I cannot just copy the external sequence to internal!

I was playing around with using something like

declare @id int
set @id = 0
update labels
set @id = intsequence = @id + 1

but not sure on how to update it in sort order?
Post #1589530
Posted Saturday, July 5, 2014 10:28 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 5:09 PM
Points: 23,089, Visits: 31,635
Can you explain why you can't copy the ExternalSequence to the InternalSequence?



Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1589532
Posted Saturday, July 5, 2014 10:37 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, July 18, 2014 11:33 PM
Points: 166, Visits: 484
It's data that has come from an external source and is different to what is required for the internal sequence. In the real system, the external sequence starts at a very large number and increases, but the internal sequence must start at 1.

I wish I could just use the ext sequence but unfortunately the business/application rules forbid it.

Post #1589533
Posted Saturday, July 5, 2014 10:46 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 5:09 PM
Points: 23,089, Visits: 31,635
So something like this (run in an empty test database):


--Example table
create table dbo.Labels
(Id int identity (1,1),
Value varchar(20),
IntSequence bigint,
ExternalSequence bigint,
BatchId int)

-- Insert some data

Insert into dbo.Labels
(Value, IntSequence, ExternalSequence, BatchId)
Values
--batch 1
('exampleValue', 1,100001,1),
('exampleValue', 2,100002,1),
('exampleValue', 3,100003,1),
--batch 2
('exampleValue', 4,100006,2),
('exampleValue', 5,100007,2),
('exampleValue', 6,100008,2),
-- batch 3
('exampleValue', 7,100010,3),
('exampleValue', 8,100011,3),
-- Insert the missing values for batch 1
('exampleValue', 9,100004,1),
('exampleValue', 10,100005,1),
-- insert the missing values for batch 2
('exampleValue', 11,100009,2)

select * from dbo.Labels order by IntSequence asc; -- Current order showing external seq in wrong order, but internal seq in correct order.
select * from dbo.Labels order by ExternalSequence asc; -- Order by the other column which is in correct order shows true order, but internal sequence in wrong order

with basedata as (
select
Value,
IntSequence,
ExternalSequence,
BatchId,
rn = row_number() over (order by BatchId, ExternalSequence)
from
dbo.Labels
)
update basedata set
IntSequence = rn;



select * from dbo.Labels order by IntSequence; -- Current order showing external seq in wrong order, but internal seq in correct order.
select * from dbo.Labels order by ExternalSequence asc -- Order by the other column which is in correct order shows true order, but internal sequence in wrong order


drop table dbo.Labels;





Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1589535
Posted Saturday, July 5, 2014 10:53 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, July 18, 2014 11:33 PM
Points: 166, Visits: 484
Perfect! Thanks so much.

I was on to something a tiny bit similar myself, but for some reason my code doesn't change the data at all.

declare @id bigint
set @id = 0;
With cte As
(
select IntSequence, ROW_NUMBER() OVER (order by externalsequence asc) as rownumber from labels
)

update cte
set @id = IntSequence = @id + 1

That's a big help. Thanks again.
Post #1589537
Posted Saturday, July 5, 2014 10:56 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 5:09 PM
Points: 23,089, Visits: 31,635
This is all you needed:


With cte As
(
select IntSequence, ROW_NUMBER() OVER (order by externalsequence asc) as rownumber from labels
)

update cte
set IntSequence = rownumber;





Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1589538
Posted Saturday, July 5, 2014 11:07 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, July 18, 2014 11:33 PM
Points: 166, Visits: 484
Seems so simple now!

Perfect thanks.
Post #1589539
Posted Saturday, July 5, 2014 6:20 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 4:53 PM
Points: 36,795, Visits: 31,257
I might be missing something but I guess my question would be, why use the internal sequence at all? Just use the external sequence?


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1589575
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse