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


using between on string columns


using between on string columns

Author
Message
cgreathouse
cgreathouse
SSC-Enthusiastic
SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)

Group: General Forum Members
Points: 147 Visits: 373
This is puzzling.

I've run across a case where using between on string columns returns rows I'm not expecting. The following code will demonstrate the issue


declare @t table(Start varchar(10)
,[End] varchar(10))

insert @t
values('1500','1599')
,('2400','2799')
,('1','599')
,('2800','2999')
,('700','799')
,('A1','A3')
,('B4','B9')

declare @val varchar(10)
set @val = '2609'

select *
from @t
where @val between Start and [End]



I'm only expect to get 1 row back. But instead 2 rows are returning. Here's what is coming back..


Start End

2400 2799
1 599


I can't figure out why the 1, 599 row is coming back. Does anybody have any ideas why this is happening?

Thanks!
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (210K reputation)SSC Guru (210K reputation)SSC Guru (210K reputation)SSC Guru (210K reputation)SSC Guru (210K reputation)SSC Guru (210K reputation)SSC Guru (210K reputation)SSC Guru (210K reputation)

Group: General Forum Members
Points: 210777 Visits: 41973
It's because the leading "2" falls between the leading "1" and the leading "5". You would need to LPAD the contents of the table and the string contained in @val to the same right justified length for it to work correctly.

--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
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (210K reputation)SSC Guru (210K reputation)SSC Guru (210K reputation)SSC Guru (210K reputation)SSC Guru (210K reputation)SSC Guru (210K reputation)SSC Guru (210K reputation)SSC Guru (210K reputation)

Group: General Forum Members
Points: 210777 Visits: 41973
Here's your string example with the proper justification for jusing BETWEEN for such things. It returns the correct value, as expected.


declare @t table(Start varchar(10)
,[End] varchar(10))

insert @t
values('1500','1599')
,('2400','2799')
,(' 1',' 599')
,('2800','2999')
,(' 700',' 799')
,(' A1',' A3')
,(' B4',' B9')

declare @val varchar(10)
set @val = '2609'

select *
from @t
where @val between Start and [End]




Think of a dictionary because that's how strings work for this. If the "1" where an "A" and the "599" were "Egg", where would you the word "Bang" (your 2609) to appear even though it has more letters than either of the other 2? The same holds true for strings that look like numbers.

--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
dr.blowfin
dr.blowfin
SSC-Enthusiastic
SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)SSC-Enthusiastic (134 reputation)

Group: General Forum Members
Points: 134 Visits: 256
Interesting, this is probably context specific, but how does SQL deal with the alphanumeric "numbers" in that table? Say we pad all the values and choose an @val which is in the middle of one of the "Hex Looking" values.

declare @t table(Start varchar(10)
,[End] varchar(10))

insert @t
values('1500','1599')
,('2400','2799')
,('0001','0599')
,('2800','2999')
,('0700','0799')
,('00A1','00A3')
,('00B4','00B9')

declare @val varchar(10)
set @val = '00A2'

select *
from @t
where @val between Start and [end]



We get back 2 rows:
Start   End
0001 0599
00A1 00A3



I'm sure we're looking at the same thing come into play, but would there be any value in doing some conversion to a common format with the strings? Are they even supposed to be in the same base?

Edit: getting the same results padding with spaces too.

Think of a dictionary because that's how strings work for this. If the "1" where an "A" and the "599" were "Egg", where would you the word "Bang" (your 2609) to appear even though it has more letters than either of the other 2? The same holds true for strings that look like numbers.


Good explanation, most of this post can probably be ignored. I think I'm just worried by the fact that the data seems inconsistent for the purpose of the example :-P
cgreathouse
cgreathouse
SSC-Enthusiastic
SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)SSC-Enthusiastic (147 reputation)

Group: General Forum Members
Points: 147 Visits: 373
Thanks! I must have total spaced. I should have know why that was happening.

I liked the idea with padding with spaces but if I tried to use @val=2 then nothing would come back. I would have to know how many spaces to pad @val with. Paddding with 0s doesn't solve it either.

So here's what I came up with


declare @t table(Start varchar(10)
,[End] varchar(10)
,StartLen as len(Start)
,EndLen as len([End]))

insert @t
values('1500','1599')
,('2400','2799')
,('1','599')
,('2800','2999')
,('700','799')
,('A1','A3')
,('B4','B9')

declare @val varchar(10)
set @val = '2609'

select *
from @t
where @val between Start and [End]
and len(@val) between StartLen and EndLen



This seems to do the trick.

The actual table is pretty static. It's only updated a few times a year. I'll play around with adding an index on the computed columns to see if that gives any performance benefit.

Thanks!
Steven Willis
Steven Willis
SSCommitted
SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)

Group: General Forum Members
Points: 1989 Visits: 1721
You can pad the string values for proper sorting using the REPLICATE operator.

For example:



DECLARE @val VARCHAR(10)
SET @val = '2609'

DECLARE @t TABLE
(
[Start] VARCHAR(10)
,[End] VARCHAR(10)
)

INSERT @t
VALUES
('1500','1599')
, ('2400','2799')
, ('1','599')
, ('2800','2999')
, ('700','799')
, ('A1','A3')
, ('B4','B9')

SELECT
Start
,[End]
FROM
@t
WHERE
@val BETWEEN [Start] AND [End]





Your output:
Start End
2400 2799
1 599





SELECT
r.[Start]
,r.[End]
FROM
(
SELECT
[Start]+REPLICATE('0',6-LEN([Start])) AS [Start]
,[End]+REPLICATE('0',6-LEN([End])) AS [End]
FROM
@t
) r
WHERE
@val BETWEEN [Start] AND [End]





Output padded right:
Start End
240000 279900
100000 599000





SET @val = '002609'

SELECT
r.[Start]
,r.[End]
FROM
(
SELECT
REPLICATE('0',6-LEN([Start]))+[Start] AS [Start]
,REPLICATE('0',6-LEN([End]))+[End] AS [End]
FROM
@t
) r
WHERE
@val BETWEEN [Start] AND [End]





Output padded left:
Start End
002400 002799



 
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