July 22, 2013 at 8:29 pm
Ok I hope I can explain my dilema
I need a sql select statement that will
Select part_number from RCTOOL
the column part_number has values such as
BR643-0034-344-34
AS54-54689
A77360-3454-34456-4
B7374-343-33-32-356-433-11-1
In each of these cases ALL we want it to return is the values UP to the last -
Desired result set from example above
BR643-0034-344
AS54
A77360-3454-34456
B7374-343-33-32-356-433-11
Thank you in advance
July 22, 2013 at 10:59 pm
See http://www.sqlservercentral.com/articles/Tally+Table/72993/[/url]
to get the code and explanation for use of the DelimitedSplit8K function.
;WITH SampleData (ID,PartNumber)
AS
(
SELECT 1,'BR643-0034-344-34' UNION ALL
SELECT 2,'AS54-54689' UNION ALL
SELECT 3,'A77360-3454-34456-4' UNION ALL
SELECT 4,'B7374-343-33-32-356-433-11-1'
)
SELECT
r.PartNumber
,LEFT(r.PartNumber,LEN(r.PartNumber)-LEN(r.Item)-1) AS NewPartNumber
FROM
(
SELECT
ID
,PartNumber
,ItemNumber
,Item
,(MAX(ItemNumber) OVER (PARTITION BY PartNumber)) AS MaxItem
FROM
SampleData AS s
CROSS APPLY
dbo.DelimitedSplit8K(s.PartNumber,'-') AS dsk
) r
WHERE
r.ItemNumber = r.MaxItem
ORDER BY
r.ID
July 22, 2013 at 11:12 pm
Thank you for the reply and query - this table could have thousands of values I was just trying to give you an IDEA of some of the values but the key is we ALWAYS want it to yield everything UP to the last - in the record? Will what you gave us work on more than just those four examples I gave you that are in the 'Sample" data section??
July 23, 2013 at 12:01 am
I'm as big an advocate of DelimitedSplit8K in the SQLverse as you're gonna find, but in this case I'd say there's a simpler way:
;WITH SampleData (ID,PartNumber)
AS
(
SELECT 1,'BR643-0034-344-34' UNION ALL
SELECT 2,'AS54-54689' UNION ALL
SELECT 3,'A77360-3454-34456-4' UNION ALL
SELECT 4,'B7374-343-33-32-356-433-11-1' UNION ALL
SELECT 5,'B7374'
)
SELECT ID, LEFT(PartNumber, LEN(PartNumber)-CHARINDEX('-', REVERSE(PartNumber)))
FROM SampleData
It even handles cases where there is no hyphen at all in the part number.
Note that I don't mean to imply that Steven's solution doesn't handle this case.
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
July 23, 2013 at 12:04 am
I think this would still work for you. But the important point is to take a look at the article link I posted and learn how to use DelimitedSplit8K. That function can split your part numbers into the individual pieces and place them into table form. Then in this case all you have to do is drop the last item and concantenate the others back together or just use string logic as here to do a replace.
The split is the critical part...the method you choose to toss away the undesired value would depend on whether this is a one-time deal or for production. If just a one time conversion, then this would probably do the trick. If I was going to do this in real-time indefinitely in a production environment I'd probably go with doing the split and then using FOR XML PATH to create the new part numbers.
Or turn the entire part number (post-split less the undesired column) into an XML file. The code I posted deals with the issue of an unequal number of elements in each part number, but can be turned into XML easily. Once that's done then the XML can be parsed by a number of different methods.
;WITH SampleData (UniqueID,PartNumber)
AS
(
SELECT 1,'BR643-0034-344-34' UNION ALL
SELECT 2,'AS54-54689' UNION ALL
SELECT 3,'A77360-3454-34456-4' UNION ALL
SELECT 4,'B7374-343-33-32-356-433-11-1'
)
SELECT
CAST(r.UniqueID AS VARCHAR(10)) AS 'ID/@UniqueID'
,(SELECT LEFT(r.PartNumber,LEN(r.PartNumber)-LEN(r.Item)-1)) AS 'ID/@PartNumber'
FROM
(
SELECT
UniqueID
,PartNumber
,ItemNumber
,Item
,(MAX(ItemNumber) OVER (PARTITION BY PartNumber)) AS MaxItem
FROM
SampleData AS s
CROSS APPLY
dbo.DelimitedSplit8K(s.PartNumber,'-') AS dsk
) r
WHERE
r.ItemNumber = r.MaxItem
ORDER BY
r.UniqueID
FOR XML PATH(''), ROOT('root')
<root>
<ID UniqueID="1" PartNumber="BR643-0034-344" />
<ID UniqueID="2" PartNumber="AS54" />
<ID UniqueID="3" PartNumber="A77360-3454-34456" />
<ID UniqueID="4" PartNumber="B7374-343-33-32-356-433-11" />
</root>
EXEC dbo.ParseXMLtoTable
'<root>
<ID UniqueID="1" PartNumber="BR643-0034-344" />
<ID UniqueID="2" PartNumber="AS54" />
<ID UniqueID="3" PartNumber="A77360-3454-34456" />
<ID UniqueID="4" PartNumber="B7374-343-33-32-356-433-11" />
</root>'
,'root'
July 23, 2013 at 12:09 am
Yeah, I suppose I can over-complicate things at times. 😛
There's so many ways to do this stuff that it's easy to get lost in the pursuit.
July 23, 2013 at 12:26 am
Thank you BOTH so much - I am good to go and am so thankful for the query help and the wonderful link! Have a great night to you both!
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply