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

SubString Expand / Collapse
Author
Message
Posted Tuesday, February 23, 2010 8:30 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, July 25, 2012 7:56 AM
Points: 140, Visits: 354
I have a field in my SSIS package formatted as follows:

5/3/233634$00
5/2/126902$00
1/64/78326$01
5/52/66352$01
1/172/503570$01
1/126/99955$01
1/172/503571$01
9/7/44633$01
3/23/38300$01
3/10/43869$01
1/52/157940$01
1/126/99956$01
1/171/200563$01

I need to split this into three fields:

Field 1 - The digit(s) to the left of the FIRST "/"
Field 2 - The digit(s) BETWEEN the two "/"s
Field 3 - The digits between the SECOND "/2 and the "$"

Try as I might, I cannot get this to work on my Derived Column transformation.
Can someone please help?

Paul
Post #871178
Posted Tuesday, February 23, 2010 9:16 AM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Thursday, July 17, 2014 4:13 AM
Points: 76, Visits: 113
SUBSTRING within Derived Column is ur answer. try using sequence of substrings to achieve this.
Post #871234
Posted Wednesday, February 24, 2010 1:24 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, July 25, 2012 7:56 AM
Points: 140, Visits: 354
I have tried the following:

For Field 1 - SUBSTRING([RefNumber],1,1)
This correctly returns the first digit.

For Field 3 - SUBSTRING([RefNumber],FINDSTRING("/",[RefNumber],3),(FINDSTRING("$",[RefNumber],3)) - FINDSTRING("/",[RefNumber],3))
This is accepted by the Derived COlumn transformation, but when I debug the package it fails with the following:
[Derived Column [4862]] Error: SSIS Error Code DTS_E_INDUCEDTRANSFORMFAILUREONERROR. The "component "Derived Column" (4862)" failed because error code 0xC0049067 occurred, and the error row disposition on "output column "Derived Column 1" (10186)" specifies failure on error. An error occurred on the specified object of the specified component. There may be error messages posted before this with more information about the failure.
[Derived Column [4862]] Error: An error occurred while evaluating the function.

Can anyone help me please?

Paul
Post #871767
Posted Wednesday, February 24, 2010 2:17 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, July 25, 2012 7:56 AM
Points: 140, Visits: 354
An update:

I now have this functionality working in T-SQL.. bu tI would dearly LOVE to have the expression in the Derived Column do this job.


In T-SQL I am using the following:

select

RefNumber,SUBSTRING(RefNumber, 1, (CHARINDEX('/',[RefNumber],1 )-1)) as Store,

SUBSTRING([RefNumber],(CHARINDEX('/',[RefNumber],1 )+1),(CHARINDEX('/',[RefNumber],4)) - (CHARINDEX('/',[RefNumber],1)+1)) as Till,

SUBSTRING([RefNumber],(CHARINDEX('/',[RefNumber],4 )+1),(CHARINDEX('$',[RefNumber],4)) - (CHARINDEX('/',[RefNumber],4)+1)) as Trans_Num
from imported_data

select
SUBSTRING([RefNumber],(CHARINDEX('/',[RefNumber],1 )+1),(CHARINDEX('/',[RefNumber],3)) - (CHARINDEX('/',[RefNumber],1)+1)) as Trans_Num
from RefTable





which is returning the data in the format I'd like it.
Can anyone give me a pointer?

Paul
Post #871784
Posted Thursday, February 25, 2010 2:56 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 4:07 AM
Points: 13,543, Visits: 11,350
Paul_Harvey (2/24/2010)

For Field 3 - SUBSTRING([RefNumber],FINDSTRING("/",[RefNumber],3),(FINDSTRING("$",[RefNumber],3)) - FINDSTRING("/",[RefNumber],3))
This is accepted by the Derived COlumn transformation, but when I debug the package it fails with the following:
[Derived Column [4862]] Error: SSIS Error Code DTS_E_INDUCEDTRANSFORMFAILUREONERROR.


The 3rd argument of Findstring specifies which occurrence of the 2nd argument you want. You've placed the number 3 there for backslash, but I only count 2 for backslash and also 3 for $, but I only see one.

Try:

SUBSTRING([RefNumber],FINDSTRING("/",[RefNumber],2),(FINDSTRING("$",[RefNumber],1)) - FINDSTRING("/",[RefNumber],2))





How to post forum questions.
Need an answer? No, you need a question.
What’s the deal with Excel & SSIS?

Member of LinkedIn. My blog at LessThanDot.

MCSA SQL Server 2012 - MCSE Business Intelligence
Post #872554
Posted Thursday, February 25, 2010 3:03 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, July 25, 2012 7:56 AM
Points: 140, Visits: 354
Really? I thought the third argument specified how many characters to use.

SUBSTRING(fieldname,start_position, number of characters)

I'll look into this.
Post #872557
Posted Thursday, February 25, 2010 3:05 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, July 25, 2012 7:56 AM
Points: 140, Visits: 354
My apologies. I didn't read properly!
You are refering to FINDSTRING, not SUBSTRING.
Thanks for the pointer. I'll give it a go.

Paul
Post #872559
Posted Monday, March 1, 2010 6:15 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, July 25, 2012 7:56 AM
Points: 140, Visits: 354
Thanks for your help on this one, Da Zero.
Great advice!

Paul
Post #874379
Posted Monday, March 1, 2010 7:37 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 4:07 AM
Points: 13,543, Visits: 11,350
No problem at all!
I'm glad to help.




How to post forum questions.
Need an answer? No, you need a question.
What’s the deal with Excel & SSIS?

Member of LinkedIn. My blog at LessThanDot.

MCSA SQL Server 2012 - MCSE Business Intelligence
Post #874412
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse