Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

Need Charindex to Pick Up the Second Instance Expand / Collapse
Author
Message
Posted Friday, October 28, 2011 3:53 PM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Wednesday, July 23, 2014 3:57 PM
Points: 227, Visits: 455
I have a sample of a table:

--===== If the test table already exists, drop it     

IF OBJECT_ID('TempDB..#JobName','U') IS NOT NULL DROP TABLE #DateTest
GO

--===== Create the test table

CREATE TABLE #JobName(
JobName NVARCHAR(100)
)

--===== Insert the test data into the test table
INSERT INTO #JobName (Item, OrderDate)

SELECT 'InventoryCostReport_620013_SyteLine_HQ_App_Plt' UNION ALL
SELECT 'Scheduling_3113457_SyteLine_HQ_App' UNION ALL
SELECT 'ATP_CycleCountSummaryRpt_1792547_SyteLine_HQ_App' UNION ALL
SELECT 'SCRM_EmployeeTardyReport_1301630_SyteLine_HQ_App' UNION ALL
SELECT 'SPM_WarRoomReport_2695868_SyteLine_HQ_App' UNION ALL
SELECT 'SP_WarRoomReportPastDue_3061579_SyteLine_HQ_App' UNION ALL
SELECT 'TotalInventoryValuebyAcctReport_714769_SyteLine_HQ_App' UNION ALL
SELECT 'VouchersPayableReport_3128272_SyteLine_HQ_App'

--==== SELECT the records

SELECT * FROM #JobName

I want to pull all of the records everything from the number over truncated, like so:

JobName
-----------------------------------------------
InventoryCostReport
Scheduling
ATP_CycleCountSummaryRpt
SCRM_EmployeeTardyReport
SPM_WarRoomReport
SP_WarRoomReportPastDue
TotalInventoryValuebyAcctReport
VouchersPayableReport


When I use this code:

SELECT LEFT(JobName, charindex('_', JobName)-1) JobName FROM #JobName 
where substring(JobName, charindex('_', JobName)+1, 1) BETWEEN '1' AND '9'

I get this result instead:

JobName
----------------------------------
InventoryCostReport
Scheduling
TotalInventoryValuebyAcctReport
VouchersPayableReport

How can I get the code to overlook the underscore when it is followed by a letter? It seems that it only looks at the first underscore, regardless.

If you need any more information, please let me know.

Thanks.

Steve
Post #1197685
Posted Saturday, October 29, 2011 1:29 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 7:41 PM
Points: 23,033, Visits: 31,555
You need PATINDEX, try this:

IF OBJECT_ID('TempDB..#JobName','U') IS NOT NULL
DROP TABLE #JobName;

GO
--===== Create the test table
CREATE TABLE #JobName(
JobName NVARCHAR(100)
);
--===== Insert the test data into the test table
INSERT INTO #JobName (JobName)
SELECT 'InventoryCostReport_620013_SyteLine_HQ_App_Plt'
UNION ALL
SELECT 'Scheduling_3113457_SyteLine_HQ_App'
UNION ALL
SELECT 'ATP_CycleCountSummaryRpt_1792547_SyteLine_HQ_App'
UNION ALL
SELECT 'SCRM_EmployeeTardyReport_1301630_SyteLine_HQ_App'
UNION ALL
SELECT 'SPM_WarRoomReport_2695868_SyteLine_HQ_App'
UNION ALL
SELECT 'SP_WarRoomReportPastDue_3061579_SyteLine_HQ_App'
UNION ALL
SELECT 'TotalInventoryValuebyAcctReport_714769_SyteLine_HQ_App'
UNION ALL
SELECT 'VouchersPayableReport_3128272_SyteLine_HQ_App';
--==== SELECT the records
SELECT * FROM #JobName;

select left(JobName, patindex('%_[0-9]%', JobName) - 1) from #JobName;

drop table #JobName;

By the way, the code you posted doesn't work, I needed to make changes to get it to work.



Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1197719
Posted Monday, October 31, 2011 9:50 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Wednesday, July 23, 2014 3:57 PM
Points: 227, Visits: 455
Lynn,

Thank you very much for the code, and also for correcting what I had sent. This works fine except for one thing; I get this message when I run it:

Msg 536, Level 16, State 3, Line 1
Invalid length parameter passed to the substring function.

When I take out the '- 1' it works fine, but obviously gives me more everything.
Post #1198158
Posted Monday, October 31, 2011 10:58 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 7:41 PM
Points: 23,033, Visits: 31,555
sdownen05 (10/31/2011)
Lynn,

Thank you very much for the code, and also for correcting what I had sent. This works fine except for one thing; I get this message when I run it:

Msg 536, Level 16, State 3, Line 1
Invalid length parameter passed to the substring function.

When I take out the '- 1' it works fine, but obviously gives me more everything.


Must be a data issue. I don't get that error with the data you provided. You should check the data in your table to see if there is something not accounted for in the sample data.



Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1198222
Posted Monday, October 31, 2011 1:08 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Yesterday @ 11:08 PM
Points: 21,385, Visits: 9,602
Add a NULLIF(patindex, 0).

NULL -1 => NULL

LEFT ('string', NULL) doesn't die on you.
Post #1198271
Posted Monday, October 31, 2011 3:42 PM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Wednesday, July 23, 2014 3:57 PM
Points: 227, Visits: 455
You are right, Lynn. I didn't give you enough sample data. However, I have figured out a way around it. Thank you for your help.

Steve
Post #1198359
Posted Monday, October 31, 2011 8:56 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 7:30 PM
Points: 36,766, Visits: 31,222
sdownen05 (10/31/2011)
You are right, Lynn. I didn't give you enough sample data. However, I have figured out a way around it. Thank you for your help.

Steve


Two way street here, Steve. Please explain the work around you did. Thanks.


--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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1198427
Posted Monday, October 31, 2011 9:43 PM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Wednesday, July 23, 2014 3:57 PM
Points: 227, Visits: 455
Not a problem, Jeff. Thanks for calling me on that.

I only want records that end in '_Syteline_HQ_App', so I just did this:

select left(JobName, patindex('%_[0-9]%', JobName) - 1) 
from #JobName where JobName like '%_Syteline_HQ_App'

I know it doesn't solve everyone's problem, but it takes care of this one.

However, I just noticed Ninja's_RGR'us post. That code is much better than mine.

Thank you all for everything, and I will remember to contribute more. You all have taught me a lot in a short amount of time.

Steve
Post #1198433
Posted Tuesday, November 1, 2011 4:27 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Yesterday @ 11:08 PM
Points: 21,385, Visits: 9,602
sdownen05 (10/31/2011)
Not a problem, Jeff. Thanks for calling me on that.

I only want records that end in '_Syteline_HQ_App', so I just did this:

select left(JobName, patindex('%_[0-9]%', JobName) - 1) 
from #JobName where JobName like '%_Syteline_HQ_App'

I know it doesn't solve everyone's problem, but it takes care of this one.

However, I just noticed Ninja's_RGR'us post. That code is much better than mine.

Thank you all for everything, and I will remember to contribute more. You all have taught me a lot in a short amount of time.

Steve


Glad it helped.

In the best of both worlds you'd both filter the data down as much as possible and protect yourself from the left failing on you. Being able to do both without forcing a table scan is always a good option .

P.S. It's the same trick when doing avgs => SUM(a) / SUM(b) => Divide by 0 error. However / NULLIF(SUM(b), 0) won't fail on you either.

Very useful to know .
Post #1198527
Posted Tuesday, November 1, 2011 7:30 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 7:30 PM
Points: 36,766, Visits: 31,222
sdownen05 (10/31/2011)
Not a problem, Jeff. Thanks for calling me on that.

....
However, I just noticed Ninja's_RGR'us post. That code is much better than mine.


Thanks, Steve. That's the spirit. Now you know the 2 reasons why I ask for such a thing...

1. We all might learn something new from you especially since you're the closest to the problem.

2. We do a double check on your code for you just to make sure. Think of it as a "peer review" to try to help keep you out of trouble. I've seen lots of folks coin their own solution from suggestions and have it turn out wrong.


--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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1198651
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse