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


Obtaining unique data


Obtaining unique data

Author
Message
J M-314995
J M-314995
Mr or Mrs. 500
Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)

Group: General Forum Members
Points: 557 Visits: 328
Here's my simplified table...

Invoice_id
897456-0001
897456-0002
897456-0003
898657-0001
898657-0004
889977-0003
889978-0002
889978-0004
889979-0001
889979-0010
889995-0002
889995-0003
889995-0004

I want to write a script so that it returns the following results...

889977-0003
889978-0002
889978-0004
889995-0002
889995-0003
889995-0004

Basically the first 6 digits are the account number and the next 4 are the invoice numbers (after the hyphen). I don't want any results on an account number if the account number has an invoice of 0001. If the account has a 0002 or higher only, I want all invoice id's returned.

How would I approach this?

TIA,
John
pietlinden
pietlinden
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13796 Visits: 14119
Use MAX
Group by the stuff before the dash.
CAST the stuff after the dash as a number, get MAX of it.
J Livingston SQL
J Livingston SQL
SSChampion
SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)

Group: General Forum Members
Points: 11979 Visits: 37516


SELECT invoice_id
FROM <YOURTABLE>
WHERE LEFT(invoice_id, 6) NOT IN
(
SELECT DISTINCT LEFT(invoice_id, 6)
FROM <YOURTABLE>
WHERE (RIGHT(invoice_id, 4) = '0001')
)




________________________________________________________________
you can lead a user to data....but you cannot make them think
and remember....every day is a school day

J M-314995
J M-314995
Mr or Mrs. 500
Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)

Group: General Forum Members
Points: 557 Visits: 328
Because I pulled the data into a temporary table from the main db, this script wasn't working. I figured out that because I took the data as is, the field was of type CHAR(20)...and it's not something mentioned in my original post so you wouldn't have known. When I changed your script to...


SELECT invoice_id
FROM <YOURTABLE>
WHERE LEFT(RTRIM(invoice_id), 6) NOT IN
(
SELECT DISTINCT LEFT(RTRIM(invoice_id), 6)
FROM <YOURTABLE>
WHERE (RIGHT(RTRIM(invoice_id), 4) = '0001')
)




...it worked beautifully.

Thanks for putting me on track with this.
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: 17479 Visits: 6431
Illustrating what PietLinden suggested, which I like because it avoids the sort inherent in DISTINCT:


WITH SampleData AS
(
SELECT invoice_no
FROM
(
VALUES ('897456-0001')
,('897456-0002')
,('897456-0003')
,('898657-0001')
,('898657-0004')
,('889977-0003')
,('889978-0002')
,('889978-0004')
,('889979-0001')
,('889979-0010')
,('889995-0002')
,('889995-0003')
,('889995-0004')
) a (invoice_no)
)
SELECT invoice_no=MAX(invoice_no)
FROM SampleData
GROUP BY LEFT(invoice_no, 6);





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
J M-314995
J M-314995
Mr or Mrs. 500
Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)Mr or Mrs. 500 (557 reputation)

Group: General Forum Members
Points: 557 Visits: 328
dwain.c (10/21/2013)
Illustrating what PietLinden suggested, which I like because it avoids the sort inherent in DISTINCT:


WITH SampleData AS
(
SELECT invoice_no
FROM
(
VALUES ('897456-0001')
,('897456-0002')
,('897456-0003')
,('898657-0001')
,('898657-0004')
,('889977-0003')
,('889978-0002')
,('889978-0004')
,('889979-0001')
,('889979-0010')
,('889995-0002')
,('889995-0003')
,('889995-0004')
) a (invoice_no)
)
SELECT invoice_no=MAX(invoice_no)
FROM SampleData
GROUP BY LEFT(invoice_no, 6);




I was actually going to come back and try PietLinden's suggestion as well. I always like learning multiple ways to complete a task. Thanks for your input.
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