Query-generated Column Expressions

  • Comments posted to this topic are about the item Query-generated Column Expressions

    Bill Nicolich: www.SQLFave.com.
    Daily tweet of what's new and interesting: AppendNow

  • Hey everyone. Not quite sure what happened, but the scripts in the article need a modification so they use a token for the column name: <column>.

    INSERT INTO #ExpressionToDataTypeAndNull

    ( DATA_TYPE ,

    IS_NULLABLE ,

    CustomExpression

    )

    VALUES

    ( 'varchar','YES','LTRIM(RTRIM(ISNULL("<column>",''''))) AS "<column>",')

    ,( 'varchar','NO','LTRIM(RTRIM("<column>")) AS "<column>",')

    ,( 'nvarchar','YES','LTRIM(RTRIM(ISNULL("<column>",''''))) AS "<column>",')

    ,( 'nvarchar','NO','LTRIM(RTRIM("<column>")) AS "<column>",')

    ,( 'datetime','YES','CAST("<column>" AS varchar(max)) AS "<column>",')

    ,( 'datetime','NO','CAST("<column>" AS varchar(max)) AS "<column>",')

    ;

    and

    DECLARE @TableName nvarchar(128)

    SET @TableName = 'FictionalEmployees'

    SELECT

    ISNULL(REPLACE(CustomExpression,'<column>', COLUMN_NAME), COLUMN_NAME + ' AS ' + COLUMN_NAME) AS ThisColumnExpression

    FROM INFORMATION_SCHEMA.COLUMNS a

    FULL OUTER JOIN #ExpressionToDataTypeAndNull b

    ON a.DATA_TYPE = b.DATA_TYPE

    AND a.IS_NULLABLE = b.IS_NULLABLE

    WHERE TABLE_NAME = @TableName

    ORDER BY ordinal_position ASC;

    Once you have the token <column> replaced by the column name, your output includes the column names as advertised in the results.

    Sorry about that! I'm not sure what happened there.

    Bill Nicolich: www.SQLFave.com.
    Daily tweet of what's new and interesting: AppendNow

  • Try to specify the alises all in one place. Save yourself some typing. Also build the full select starement. Also could be used as a create view statement. Interesting idea though.

    INSERT INTO #ExpressionToDataTypeAndNull

    ( DATA_TYPE ,

    IS_NULLABLE ,

    CustomExpression

    )

    VALUES

    ( 'varchar','YES','LTRIM(RTRIM(ISNULL("<column>",'''')))')

    ,( 'varchar','NO','LTRIM(RTRIM("<column>"))"')

    ,( 'nvarchar','YES','LTRIM(RTRIM(ISNULL("<column>",'''')))')

    ,( 'nvarchar','NO','LTRIM(RTRIM("<column>"))')

    ,( 'datetime','YES','CAST("<column>" AS varchar(max))')

    ,( 'datetime','NO','CAST("<column>" AS varchar(max))')

    ;

    DECLARE @TableName nvarchar(128)

    SET @TableName = 'FictionalEmployees'

    DECLARE @SqlSelect NVARCHAR(MAX)

    SELECT @SqlSelect = COALESCE(

    @SqlSelect + ', ' + ISNULL(REPLACE(CustomExpression,'<column>', COLUMN_NAME), COLUMN_NAME )

    , ISNULL(REPLACE(CustomExpression,'<column>', COLUMN_NAME), COLUMN_NAME )

    ) + ' AS "' + COLUMN_NAME + '"'

    FROM INFORMATION_SCHEMA.COLUMNS a

    FULL OUTER JOIN #ExpressionToDataTypeAndNull b

    ON a.DATA_TYPE = b.DATA_TYPE

    AND a.IS_NULLABLE = b.IS_NULLABLE

    WHERE TABLE_NAME = @TableName

    ORDER BY ordinal_position ASC;

    SET @SqlSelect = 'SELECT ' + @SqlSelect + 'FROM ' + @TableName

    PRINT @SqlSelect

    -- EXECUTE sp_executesql @SqlSelect

  • Hi.

    An interesting article! I just thought I'd point out that:

    "FULL OUTER JOIN allows the query to return columns that don't have a match in the #ExpressionToDataTypeAndNull table"

    is not 100% right. What you are describing is a LEFT outer join.

    A FULL outer join would return results in the opposite case too - i.e. if there were row(s) in the #ExpressionToDataTypeAndNull table for which there is no match in INFORMATION_SCHEMA.COLUMNS.

    However, as you are specifying in your WHERE clause that TABLE_NAME = @TableName, you are effectively converting your full outer join into a left outer join, (perhaps unknowingly!)

    Just wanted to clarify that, in case other readers find it misleading!

    Keep up the good work.

    Cheers,

    Nick

  • Nick Chadwick (5/25/2010)


    Hi.

    An interesting article! I just thought I'd point out that:

    Thanks Nick! You put it nicely. It's very much the case here at SSC.COM that ones peers have enough passion and interest to find something if it's amiss or point out nuances. That's one reason why I like to contribute - for the challenge and learning experience of it.

    If you don't believe me, put something in and give it a shot!

    I didn't want to lengthen the article too much, but one point I'll add is that with this technique, one can build a little library of functions and keep it handy for those ETL, Ad-hoc or other situations.

    Bill Nicolich: www.SQLFave.com.
    Daily tweet of what's new and interesting: AppendNow

  • Nick,

    This seemed to work a little better for me:

    CREATE TABLE #ExpressionToDataTypeAndNull

    (

    DATA_TYPEVARCHAR(15),

    IS_NULLABLEVARCHAR(3) ,

    CustomExpressionVARCHAR(128)

    )

    INSERT INTO #ExpressionToDataTypeAndNull( DATA_TYPE , IS_NULLABLE , CustomExpression )

    VALUES ( 'varchar','YES','LTRIM(RTRIM(ISNULL("<column>",''''))) AS "<column>"')

    INSERT INTO #ExpressionToDataTypeAndNull( DATA_TYPE , IS_NULLABLE , CustomExpression )

    VALUES ( 'varchar','NO','LTRIM(RTRIM("<column>")) AS "<column>"')

    INSERT INTO #ExpressionToDataTypeAndNull( DATA_TYPE , IS_NULLABLE , CustomExpression )

    VALUES ( 'nvarchar','YES','LTRIM(RTRIM(ISNULL("<column>",''''))) AS "<column>"')

    INSERT INTO #ExpressionToDataTypeAndNull( DATA_TYPE , IS_NULLABLE , CustomExpression )

    VALUES ( 'nvarchar','NO','LTRIM(RTRIM("<column>")) AS "<column>"')

    INSERT INTO #ExpressionToDataTypeAndNull( DATA_TYPE , IS_NULLABLE , CustomExpression )

    VALUES ( 'datetime','YES','CAST("<column>" AS varchar(max)) AS "<column>"')

    INSERT INTO #ExpressionToDataTypeAndNull( DATA_TYPE , IS_NULLABLE , CustomExpression )

    VALUES ( 'datetime','NO','CAST("<column>" AS varchar(max)) AS "<column>"')

    DECLARE @TableName VARCHAR(128)

    SET @TableName = 'EntityRelationshipCache'

    DECLARE @SqlSelect NVARCHAR(MAX)

    SELECT @SqlSelect = COALESCE( @SqlSelect + ', ' + ISNULL(REPLACE(CustomExpression,'<column>', COLUMN_NAME), COLUMN_NAME )

    , ISNULL(REPLACE(CustomExpression,'<column>', COLUMN_NAME), COLUMN_NAME ) )

    FROM INFORMATION_SCHEMA.COLUMNS a

    FULL OUTER JOIN #ExpressionToDataTypeAndNull b

    ON a.DATA_TYPE = b.DATA_TYPE

    AND a.IS_NULLABLE = b.IS_NULLABLE

    WHERE TABLE_NAME = @TableName

    ORDER BY ordinal_position ASC;

    SET @SqlSelect = 'SELECT ' + REPLACE( @SqlSelect, '"', '') + ' FROM ' + @TableName

    PRINT @SqlSelect

    --EXECUTE ( @SqlSelect )

    IF ( OBJECT_ID( 'TEMPDB..#ExpressionToDataTypeAndNull' ) IS NOT NULL )

    BEGIN

    DROP TABLE #ExpressionToDataTypeAndNull

    END

    Nice Concept,

    Doug

  • Nice concept. Thanks for sharing.

    Jason...AKA CirqueDeSQLeil
    _______________________________________________
    I have given a name to my pain...MCM SQL Server, MVP
    SQL RNNR
    Posting Performance Based Questions - Gail Shaw[/url]
    Learn Extended Events

  • Douglas Osborne-456728 (5/25/2010)


    Nick,

    This seemed to work a little better for me:

    How so? Please describe.

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

  • Bill Nicolich (5/25/2010)


    Hey everyone. Not quite sure what happened, but the scripts in the article need a modification so they use a token for the column name: <column>.

    ...

    Sorry about that! I'm not sure what happened there.

    Bill, send a correction to Steve... he'll get it in. Thanks for taking the time to write this article. Code to write code is one of the essentials to make development a wee bit faster.

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

  • Jeff Moden (5/25/2010)


    Douglas Osborne-456728 (5/25/2010)


    Nick,

    This seemed to work a little better for me:

    How so? Please describe.

    Doug has added in the "as <column>" on each expression, so that the results have named columns. Nice touch!

    Cheers,

    Nick

  • Jeff,

    I tweaked it for SQL 2005 - and I was not a fan of <column> as <column> when nothing was done to the data. Plus I don't think the final SQL generated was runnable, but that might have been me.

    Really neat concept - patterns are the way to go.

    Best,

    Doug

  • Thanks for the feedback guys.

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

Viewing 12 posts - 1 through 11 (of 11 total)

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