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


help with incrementing


help with incrementing

Author
Message
is250sp
is250sp
Ten Centuries
Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)

Group: General Forum Members
Points: 1047 Visits: 555
I am not sure if "incrementing" is the right word to describe what I need but here it goes. I am pulling data from a system to insert into another system. The source table has 2 fields that I will use to create logic to create a new unique field so that I can insert into the target table.

Source table:
VENDID TYPE
ABC 1
ABC 0
ABC 0
XYZ 1
XYZ 0
XYZ 0
XYZ 0

If TYPE = 1 then VENDID, else increment by 1 for each VENDID. For example, the results would be:
ABC
ABC-01
ABC-02
XYZ
XYZ-01
XYZ-02
XYZ-03

The only solution I have right now is output to Excel and do a Fill Series but that would forever.
Sean Lange
Sean Lange
SSC Guru
SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)

Group: General Forum Members
Points: 61439 Visits: 17954
It would be a LOT easier if you could post ddl and sample data.


if OBJECT_ID('tempdb..#Something') is not null
drop table #Something

create table #Something
(
VendID char(3),
Type int
)

insert #Something
select 'ABC', 1 union all
select 'ABC', 0 union all
select 'ABC', 0 union all
select 'XYZ', 1 union all
select 'XYZ', 0 union all
select 'XYZ', 0 union all
select 'XYZ', 0;



Ok now that we have something start with let's look at how you could code this.


with NumberedVals as
(
select *, ROW_NUMBER() over(partition by VENDID, Type order by (select 0)) as RowNum
from #Something
)

select VendID, Type, case Type when 1 then VendID else VendID + '-0' + CAST(RowNum as varchar(4)) end
from NumberedVals



_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Abu Dina
Abu Dina
SSCrazy
SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)

Group: General Forum Members
Points: 2911 Visits: 3325
Arggh Sean you beat me to it lol, anyhoo here is my attempt:

with SCC_CTE(VENDID, VENDTYPE)
as (select 'ABC', 1 union all
select 'ABC', 0 union all
select 'ABC', 0 union all
select 'XYZ', 1 union all
select 'XYZ', 0 union all
select 'XYZ', 0 union all
select 'XYZ', 0)

select vendid,vendtype,
case when vendtype = 1 then vendid else VENDID + '-' + right('0'+theRank, 3) end
from (

select VENDID, VENDTYPE, cast(row_number() OVER (PARTITION BY VENDID, VENDTYPE ORDER BY VENDID) as varchar) as theRank
from scc_cte) as a



---------------------------------------------------------


It takes a minimal capacity for rational thought to see that the corporate 'free press' is a structurally irrational and biased, and extremely violent, system of elite propaganda.
David Edwards - Media lens

Society has varying and conflicting interests; what is called objectivity is the disguise of one of these interests - that of neutrality. But neutrality is a fiction in an unneutral world. There are victims, there are executioners, and there are bystanders... and the 'objectivity' of the bystander calls for inaction while other heads fall.
Howard Zinn
ChrisM@Work
ChrisM@Work
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40714 Visits: 20000
;WITH Source_table (VENDID, [TYPE]) AS
(SELECT 'ABC', 1 UNION ALL
SELECT 'ABC', 0 UNION ALL
SELECT 'ABC', 0 UNION ALL
SELECT 'XYZ', 1 UNION ALL
SELECT 'XYZ', 0 UNION ALL
SELECT 'XYZ', 0 UNION ALL
SELECT 'XYZ', 0 )
SELECT
VENDID,
[TYPE],
NewVENDID = CASE
WHEN [TYPE] = 1 THEN VENDID
ELSE VENDID + '-' + RIGHT('00'+CAST(ROW_NUMBER() OVER(PARTITION BY VENDID, TYPE ORDER BY VENDID, TYPE) AS VARCHAR(2)),2) END
FROM Source_table
ORDER BY NewVENDID




“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
is250sp
is250sp
Ten Centuries
Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)

Group: General Forum Members
Points: 1047 Visits: 555
Wow you guys are fast! Now I have to dissect the code to understand it. Thanks!
dwain.c
dwain.c
SSCoach
SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)

Group: General Forum Members
Points: 17459 Visits: 6431
Here's another approach for your dissection table:


with SCC_CTE(VENDID, VENDTYPE)
as (select 'ABC', 1 union all
select 'ABC', 0 union all
select 'ABC', 0 union all
select 'XYZ', 1 union all
select 'XYZ', 0 union all
select 'XYZ', 0 union all
select 'XYZ', 0)

SELECT ISNULL(
VENDID + '-' + RIGHT('00' +
CAST(
NULLIF(VENDTYPE,1)+ROW_NUMBER() OVER (PARTITION BY VENDID ORDER BY VENDTYPE DESC)-1
AS VARCHAR(2)), 2)
, VENDID)
FROM SCC_CTE;





My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
ck9663
ck9663
SSC Veteran
SSC Veteran (201 reputation)SSC Veteran (201 reputation)SSC Veteran (201 reputation)SSC Veteran (201 reputation)SSC Veteran (201 reputation)SSC Veteran (201 reputation)SSC Veteran (201 reputation)SSC Veteran (201 reputation)

Group: General Forum Members
Points: 201 Visits: 111
How about something with no CTE nor subquery...

I'll borrow the population of test data...


if OBJECT_ID('tempdb..#Something') is not null
drop table #Something

create table #Something
(
VendID char(3),
Type int
)

insert #Something
select 'ABC', 1 union all
select 'ABC', 0 union all
select 'ABC', 0 union all
select 'XYZ', 1 union all
select 'XYZ', 0 union all
select 'XYZ', 0 union all
select 'XYZ', 0;



Here's the code for your required output


select
vendid, type,
new_vendid = vendid + case when type = 1 then '' else '-' + right('0' + cast(row_number() over(partition by vendid order by vendid asc, type desc) - 1 as varchar(2)),2) end
from #something


Happy Coding!!!


~~ CKK
dwain.c
dwain.c
SSCoach
SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)

Group: General Forum Members
Points: 17459 Visits: 6431
ck9663 (8/6/2013)
How about something with no CTE nor subquery...

...

~~ CKK


?? Mine has neither. The CTE is only there to put the sample data someplace.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)

Group: General Forum Members
Points: 211241 Visits: 41977
I wouldn't aadd the sequence number to the original data because it makes it more difficult to use criteria not to mention that it's a form of denormalization. The sequence number should go into a different column. If you absolutely need to append the sequence number to the original data, do it only at display time.

--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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
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