Problem with data conversion

  • I'm trying to import a flat file into a table in my SQL Server database. However, the derived column transformation is giving an error but only on certain columns and certain rows, but we can't find out why.

    The data in the file is as showed below.

    4762040400085003 000539021910000541161240001074615170000870464640000579997880001019609700000626533310001411425950001035889150001011675240000930959670001031754130

    4762040400093338 00000069788p00000069788p00000069788p00000069788p00000069788p00000069788p00000069788p00000069788p00000069788p00000069788p00000069788p00000069788p

    4762040400094930 000214147680001095445120000462680660000812678980000872152370000580503800000626533310001411425950001035889150001011675240000930959670001031754130

    The rows are divided into one column of 19 chars and 12 of 12 chars. Each of the 12 chars columns represents a decimal and if it ends on p it should be negative.

    The first 2 lines are converted successfully but the 3rd line throws an error on Columns 3, 9, 10, 11 & 13 and returns NULL values.

    The code used to transform the columns is the following.

    SUBSTRING([Column 2],12,1) == "p" ? (DT_NUMERIC,12,3)SUBSTRING([Column 2],1,11) * @[User::Negative] : (DT_NUMERIC,12,3)SUBSTRING([Column 2],1,12) * @[User::Positive]

    Do you have any idea on what's happening? Should I use something different for this instead of the derived column?

    If more info is needed, please tell me.

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • What's the error?

    At first sight nothing is wrong with the expression.

    Need an answer? No, you need a question
    My blog at https://sqlkover.com.
    MCSE Business Intelligence - Microsoft Data Platform MVP

  • Hi Koen,

    The expression works on most cases but on some values it just returns NULLS when it ignores failures or the following errors that make the task fail.

    [Derived Column [187]] Error: SSIS Error Code DTS_E_INDUCEDTRANSFORMFAILUREONERROR.

    The "component "Derived Column" (187)" failed because error code 0xC0049063 occurred,

    and the error row disposition on "output column "Derived Column 3" (250)"

    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 [187]] Error: SSIS Error Code DTS_E_INDUCEDTRANSFORMFAILUREONERROR.

    The "component "Derived Column" (187)" failed because error code 0xC0049063 occurred, and the error row disposition

    on "output column "Derived Column 3" (250)" 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.

    [SSIS.Pipeline] Error: SSIS Error Code DTS_E_PROCESSINPUTFAILED.

    The ProcessInput method on component "Derived Column" (187) failed

    with error code 0xC0209029 while processing input "Derived Column Input" (188).

    The identified component returned an error from the ProcessInput method. The error is specific

    to the component, but the error is fatal and will cause the Data Flow task to stop running.

    There may be error messages posted before this with more information about the failure.

    [SSIS.Pipeline] Error: SSIS Error Code DTS_E_PROCESSINPUTFAILED.

    The ProcessInput method on component "Derived Column" (187) failed with error code 0xC0209029

    while processing input "Derived Column Input" (188). The identified component returned an error

    from the ProcessInput method. The error is specific to the component, but the error is fatal

    and will cause the Data Flow task to stop running. There may be error messages posted before this

    with more information about the failure.

    I'm uncertain on what could be wrong.

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • Luis Cazares (8/28/2013)


    I'm trying to import a flat file into a table in my SQL Server database. However, the derived column transformation is giving an error but only on certain columns and certain rows, but we can't find out why.

    The data in the file is as showed below.

    4762040400085003 000539021910000541161240001074615170000870464640000579997880001019609700000626533310001411425950001035889150001011675240000930959670001031754130

    4762040400093338 00000069788p00000069788p00000069788p00000069788p00000069788p00000069788p00000069788p00000069788p00000069788p00000069788p00000069788p00000069788p

    4762040400094930 000214147680001095445120000462680660000812678980000872152370000580503800000626533310001411425950001035889150001011675240000930959670001031754130

    The rows are divided into one column of 19 chars and 12 of 12 chars. Each of the 12 chars columns represents a decimal and if it ends on p it should be negative.

    The first 2 lines are converted successfully but the 3rd line throws an error on Columns 3, 9, 10, 11 & 13 and returns NULL values.

    The code used to transform the columns is the following.

    SUBSTRING([Column 2],12,1) == "p" ? (DT_NUMERIC,12,3)SUBSTRING([Column 2],1,11) * @[User::Negative] : (DT_NUMERIC,12,3)SUBSTRING([Column 2],1,12) * @[User::Positive]

    Do you have any idea on what's happening? Should I use something different for this instead of the derived column?

    If more info is needed, please tell me.

    Could it be because you've included the "sign" character "0" in your positive number by using ...

    (DT_NUMERIC,12,3)SUBSTRING([Column 2],1,[font="Arial Black"]12[/font]) * @[User::Positive]

    ... instead of ...

    (DT_NUMERIC,12,3)SUBSTRING([Column 2],1,[font="Arial Black"]11[/font]) * @[User::Positive]

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

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Thank you Jeff,

    Your suggestion gave me an idea. It was actually a precision problem. I just changed to a larger precision and it was fixed. 🙂

    Code turned out like this.

    SUBSTRING([Column 2],12,1) == "p" ? (DT_NUMERIC,16,3)SUBSTRING([Column 2],1,11) * @[User::Negative] : (DT_NUMERIC,16,3)SUBSTRING([Column 2],1,12) * @[User::Positive]

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2

Viewing 5 posts - 1 through 4 (of 4 total)

You must be logged in to reply to this topic. Login to reply