locked
Sql Invalid column name RRS feed

  • Question

  • select  money1+money2 as 'First', money3+money4 as 'Second'
      ,'First' + 'Second' as 'TOTAL'
     from person

    THE RESULT : "Sql Invalid column name"
    ---------------------------------------------------------
    (Importent Note: i can ;

    select  money1+money2 as 'First', money3+money4 as 'Second'
      ,money1+money2+money3+money4 as 'TOTAL'
     from person

    but I want the solution of the above questions

    Friday, July 18, 2014 2:06 PM

Answers

  • Hi

    try below

    i think you just asking how to access the derived column with in same select statement, Answer is you cant

    there is a way to do this using CROSS APPLY (you can multiple Cross Apply as you need to derive columns) Third example is with Cross Apply ,

    Cross Apply(i am a big fan of cross apply)

    http://bradsruminations.blogspot.in/2011/04/t-sql-tuesday-017-it-slices-it-dices-it.html

    http://sqlserverplanet.com/sql-2005/cross-apply-explained

    http://www.mssqltips.com/sqlservertip/1958/sql-server-cross-apply-and-outer-apply/

    CREATE TABLE #temp
      (
         money1 int,
         money2 int,
         money3 int,
         money4 int
      )
    
    INSERT INTO #temp
    VALUES     (1,2,3,4)
    
    --direct method
    SELECT money1 + money2 AS First,
                   money3 + money4 AS Second,
                   money1 + money2 + money3 + money4 as total
            FROM   #temp
    --derived table
    SELECT first , second,first + second total 
    FROM   (SELECT money1 + money2 AS First,
                   money3 + money4 AS Second
            FROM   #temp) a 
    --Cross Apply
    SELECT First,
           Second,
           First+Second Total
    FROM   #temp
    		Cross Apply( Values(money1+money2,money3 + money4)) CrossApplied (First, Second)


    • Edited by SaravanaC Friday, July 18, 2014 3:26 PM
    • Proposed as answer by SQL004 Sunday, July 20, 2014 5:23 PM
    • Marked as answer by Elvis Long Friday, July 25, 2014 2:13 AM
    Friday, July 18, 2014 3:25 PM
  • Deleted
    • Marked as answer by Elvis Long Friday, July 25, 2014 2:13 AM
    Friday, July 18, 2014 2:39 PM

All replies

  • select  money1+money2 as 'First', money3+money4 as 'Second'
      ,money1 + money2 + money3 + money4 as 'TOTAL'
    You can not use the alias to sum in this situation.

    • Edited by Rafael Juca Friday, July 18, 2014 2:10 PM
    • Proposed as answer by VS_SQL Friday, July 18, 2014 3:30 PM
    Friday, July 18, 2014 2:08 PM
  • SELECT first+second FROM (
    SELECT  money1+money2 as First, money3+money4 as Second
      from person) a

    Friday, July 18, 2014 2:14 PM
  • CREATE TABLE #temp
      (
         money1 VARCHAR(20),
         money2 VARCHAR(20),
         money3 VARCHAR(20),
         money4 VARCHAR(20)
      )
    
    INSERT INTO #temp
    VALUES     (1,2,3,4)
    SELECT money1 + money2                   AS First,
           money3 + money4                   AS Second,
           money1 + money2 + money3 + money4 AS TOTAL
    FROM   #temp
    
    SELECT first + second
    FROM   (SELECT money1 + money2 AS First,
                   money3 + money4 AS Second
            FROM   #temp) a 

    Please Mark This As Answer if it helps to solve the issue

    Friday, July 18, 2014 2:55 PM
  • Hi

    try below

    i think you just asking how to access the derived column with in same select statement, Answer is you cant

    there is a way to do this using CROSS APPLY (you can multiple Cross Apply as you need to derive columns) Third example is with Cross Apply ,

    Cross Apply(i am a big fan of cross apply)

    http://bradsruminations.blogspot.in/2011/04/t-sql-tuesday-017-it-slices-it-dices-it.html

    http://sqlserverplanet.com/sql-2005/cross-apply-explained

    http://www.mssqltips.com/sqlservertip/1958/sql-server-cross-apply-and-outer-apply/

    CREATE TABLE #temp
      (
         money1 int,
         money2 int,
         money3 int,
         money4 int
      )
    
    INSERT INTO #temp
    VALUES     (1,2,3,4)
    
    --direct method
    SELECT money1 + money2 AS First,
                   money3 + money4 AS Second,
                   money1 + money2 + money3 + money4 as total
            FROM   #temp
    --derived table
    SELECT first , second,first + second total 
    FROM   (SELECT money1 + money2 AS First,
                   money3 + money4 AS Second
            FROM   #temp) a 
    --Cross Apply
    SELECT First,
           Second,
           First+Second Total
    FROM   #temp
    		Cross Apply( Values(money1+money2,money3 + money4)) CrossApplied (First, Second)


    • Edited by SaravanaC Friday, July 18, 2014 3:26 PM
    • Proposed as answer by SQL004 Sunday, July 20, 2014 5:23 PM
    • Marked as answer by Elvis Long Friday, July 25, 2014 2:13 AM
    Friday, July 18, 2014 3:25 PM
  • You need to read the firt chpater of any book on SQL. Here is how a SELECT works in SQL ... at least in theory.  Real products will optimize things, but the code has to produce the same results. 

     a) Effectively materialize the CTEs in the optional WITH clause. CTE's come into existence in the order they are declared so only backward references are alllowed. A CTE can be recursive. Think of them as VIEWs that exist only in the scope of the query. In practice, if they are used once then they are implemented as an in-line macro.

     b) Start in the FROM clause and build a working table from all of the joins, unions, intersections, and whatever other table constructors are there.  The <table expression> AS <correlation name> option allows you give a name to this working table which you then have to use for the rest of the containing query.  Ther are UNION, INTERSECT and EXCEPT set constructors, LATERAL tables, table-valued function and all kinds of things happening in here. 

     c) Go to the WHERE clause and remove rows that do not pass criteria; that is, that do not test to TRUE (i.e. reject UNKNOWN and FALSE).  The WHERE clause is applied to the working set in the FROM clause.  

     d) Go to the optional GROUP BY clause, partiton the original table into groups and reduce each grouping to a *single* row, replacing the original working table with the new grouped table. The rows of a grouped table must be only group characteristics: (1) a grouping column (2) a statistic about the group (i.e. aggregate functions) (3) a function or constant(4) an expression made up of only those three items.  The original table no longer exists and you cannot reference anything in it (this was an error in early Sybase products).  

     e) Go to the optional HAVING clause and apply it against the grouped working table; if there was no GROUP BY clause, treat the entire table as one group. 

     f) Go to the SELECT clause and construct the expressions in the list. This means that the scalar subqueries, function calls and expressions in the SELECT are done after all the other clauses are done.  The AS operator can also give names to expressions in the SELECT list.  These new names come into existence all at once, but after the WHERE clause, GROUP BY clause and HAVING clause have been executed; you cannot use them in the SELECT list or the WHERE clause for that reason. 

    If there is a SELECT DISTINCT, then redundant duplicate rows are removed.  For purposes of defining a duplicate row, NULLs are treated as matching (just like in the GROUP BY).  

     g) Nested query expressions follow the usual scoping rules you would expect from a block structured language like C, Pascal, Algol, etc.  Namely, the innermost queries can reference columns and tables in the queries in which they are contained.  

     h) The ORDER BY clause is part of a cursor, not a query. The result set is passed to the cursor, which can only see the names in the SELECT clause list, and the sorting is done there.  The ORDER BY clause cannot have expression in it, or references to other columns because the result set has been converted into a sequential file structure and that is what is being sorted.  

    As you can see, things happen "all at once" in SQL, not "from left to right" as they would in a sequential file/procedural language model. In those languages, these two statements produce different results:
      READ (a, b, c) FROM File_X;
      READ (c, a, b) FROM File_X;

    while these two statements return the same data:

    SELECT a, b, c FROM Table_X;
    SELECT c, a, b FROM Table_X;

    Think about what a confused mess this statement is in the SQL model.

    SELECT f(c2) AS c1, f(c1) AS c2 FROM Foobar;

    That is why such nonsense is illegal syntax.

    --CELKO-- Books in Celko Series for Morgan-Kaufmann Publishing: Analytics and OLAP in SQL / Data and Databases: Concepts in Practice Data / Measurements and Standards in SQL SQL for Smarties / SQL Programming Style / SQL Puzzles and Answers / Thinking in Sets / Trees and Hierarchies in SQL

    Friday, July 18, 2014 3:33 PM