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


Incremental pattern matching


Incremental pattern matching

Author
Message
liteswitch
liteswitch
SSC Journeyman
SSC Journeyman (86 reputation)SSC Journeyman (86 reputation)SSC Journeyman (86 reputation)SSC Journeyman (86 reputation)SSC Journeyman (86 reputation)SSC Journeyman (86 reputation)SSC Journeyman (86 reputation)SSC Journeyman (86 reputation)

Group: General Forum Members
Points: 86 Visits: 598
Hi all,

I've got a column, called user_code char(3) that is used to store unique codes. The patterns are as follows

Character 1 is A-Z
Character 2 is 0-9,A-Z
Character 3 is 1-9,0,A-Z

So, the data starts at

A01
A02
...
AZZ
B01
B02
..
BZZ
..
ZZZ

Now, what I need to do is write a T-SQL statement that will tell me what the next available (ie unused) user_code can be. I wish I could just do a MAX(user_code) to find the most recently used one and then work out the next value in the sequence, but it's not that simple, as the user_codes assigned aren't in any meaningful order..

If you could help me with this, that'd be awesome. There are no constraints here really, if it means creating another lookup table with all the options in, then that's allowed, as long as the solution works!
scott.pletcher
scott.pletcher
SSC Veteran
SSC Veteran (290 reputation)SSC Veteran (290 reputation)SSC Veteran (290 reputation)SSC Veteran (290 reputation)SSC Veteran (290 reputation)SSC Veteran (290 reputation)SSC Veteran (290 reputation)SSC Veteran (290 reputation)

Group: General Forum Members
Points: 290 Visits: 473
I suggest creating another table containing every possible 3-char value, clustered on that code (fillfactor 100). Then join to that table and find the first one that isn't in use.

OR

If you (almost) never delete rows where you're adding the 3-char code, delete each 3-char code from the lookup table as you insert it into the main/detail table. Then you would always just select the MIN(code3) from the lookup table.

Scott Pletcher, SQL Server MVP 2008-2010
Ben Teraberry
Ben Teraberry
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1109 Visits: 1199
Although the absolute fastest performance is going to be what Scott said, it is possible to do it inline. (And this was worth doing anyway so you could use the same logic to quickly generate the 30K codes if that's what you choose to do.)

--fake table / data
CREATE TABLE #yourTable
(user_code char(3))
INSERT INTO #yourTable (user_code)
select 'A01' union select 'A02' union select 'B01'



--query with inline tally
;WITH E1(N) AS (SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1),--6
E2(N) AS (SELECT 1 FROM E1 a, E1 b),--36
cteTally(N) AS (SELECT ROW_NUMBER() OVER (ORDER BY N) FROM E2),
cteAlphaNum AS
(select N,
Value = case when N <= 26 then char(c1.N + 64)
else cast(N - 27 as varchar) end
from cteTally c1),
cteFinalList AS
(select c1.Value + c2.Value + c3.Value as user_code
from cteAlphaNum c1
cross join cteAlphaNum c2
cross join cteAlphaNum c3
where c1.N <= 26
and (c2.N <= 26 or c3.N <> 27))
select top 1 fl.user_code
from cteFinalList fl
left join #yourTable t
on t.user_code = fl.user_code
where t.user_code is null
order by fl.user_code asc



└> bt


Forum Etiquette: How to post data/code on a forum to get the best 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