FROM (Transact-SQL)
Specifies the tables, views, derived tables, and joined tables used in DELETE, SELECT, and UPDATE statements. In the SELECT statement, the FROM clause is required except when the select list contains only constants, variables, and arithmetic expressions (no column names).
Syntax
[ FROM { <table_source> } [ ,...n ] ]
<table_source> ::=
{
table_or_view_name [ [ AS ] table_alias ] [ <tablesample_clause> ]
[ WITH ( < table_hint > [ [ , ]...n ] ) ]
| rowset_function [ [ AS ] table_alias ]
[ (bulk_column_alias [ ,...n ] ) ]
| user_defined_function [ [ AS ] table_alias ] ]
| OPENXML <openxml_clause>
| derived_table [ AS ] table_alias [ (column_alias [ ,...n ] ) ]
| <joined_table>
| <pivoted_table>
| <unpivoted_table>
| @variable [ [ AS ] table_alias ]
| @variable.function_call ( expression [ ,...n ] ) [ [ AS ] table_alias ] [ (column_alias [ ,...n ] ) ]
}
<tablesample_clause> ::=
TABLESAMPLE [SYSTEM] (sample_number [ PERCENT | ROWS ] )
[ REPEATABLE (repeat_seed ) ]
<joined_table> ::=
{
<table_source> <join_type> <table_source> ON <search_condition>
| <table_source> CROSS JOIN <table_source>
| left_table_source { CROSS | OUTER } APPLY right_table_source
| [ ( ] <joined_table> [ ) ]
}
<join_type> ::=
[ { INNER | { { LEFT | RIGHT | FULL } [ OUTER ] } } [ <join_hint> ] ]
JOIN
<pivoted_table> ::=
table_source PIVOT <pivot_clause> [ AS ] table_alias<pivot_clause> ::=(aggregate_function(value_column [ [ , ]...n ])
FOR pivot_column
IN ( <column_list> )
)
<unpivoted_table> ::=
table_source UNPIVOT <unpivot_clause> [ AS ] table_alias<unpivot_clause> ::=(value_column FOR pivot_column IN ( <column_list> ) )
<column_list> ::=column_name [ ,...n ]
Arguments
<table_source>
Specifies a table, view, table variable, or derived table source, with or without an alias, to use in the Transact-SQL statement. Up to 256 table sources can be used in a statement, although the limit varies depending on available memory and the complexity of other expressions in the query. Individual queries may not support up to 256 table sources.Note
Query performance may suffer with lots of tables referenced in a query. Compilation and optimization time is also affected by additional factors. These include the presence of indexes and indexed views on each <table_source> and the size of the <select_list> in the SELECT statement.
The order of table sources after the FROM keyword does not affect the result set that is returned. SQL Server returns errors when duplicate names appear in the FROM clause.
table_or_view_name
Is the name of a table or view.If the table or view exists in another database on the same instance of SQL Server, use a fully qualified name in the form database.schema.object_name.
If the table or view exists outside the instance of SQL Serverl, use a four-part name in the form linked_server.catalog.schema.object. For more information, see sp_addlinkedserver (Transact-SQL). A four-part name that is constructed by using the OPENDATASOURCE function as the server part of the name can also be used to specify the remote table source. When OPENDATASOURCE is specified, database_name and schema_name may not apply to all data sources and is subject to the capabilities of the OLE DB provider that accesses the remote object. For more information, see Distributed Queries.
[AS] table_alias
Is an alias for table_source that can be used either for convenience or to distinguish a table or view in a self-join or subquery. An alias is frequently a shortened table name used to refer to specific columns of the tables in a join. If the same column name exists in more than one table in the join, SQL Server requires that the column name be qualified by a table name, view name, or alias. The table name cannot be used if an alias is defined.When a derived table, rowset or table-valued function, or operator clause (such as PIVOT or UNPIVOT) is used, the required table_alias at the end of the clause is the associated table name for all columns, including grouping columns, returned.
WITH (<table_hint> )
Specifies that the query optimizer use an optimization or locking strategy with this table and for this statement. For more information, see Table Hints (Transact-SQL).rowset_function
Specifies one of the rowset functions, such as OPENROWSET, that returns an object that can be used instead of a table reference. For more information about a list of rowset functions, see Rowset Functions (Transact-SQL).Using the OPENROWSET and OPENQUERY functions to specify a remote object depends on the capabilities of the OLE DB provider that accesses the object. For more information, see Distributed Queries.
bulk_column_alias
Is an optional alias to replace a column name in the result set. Column aliases are allowed only in SELECT statements that use the OPENROWSET function with the BULK option. When you use bulk_column_alias, specify an alias for every table column in the same order as the columns in the file.Note
This alias overrides the NAME attribute in the COLUMN elements of an XML format file, if present.
user_defined_function
Specifies a table-valued function.OPENXML <openxml_clause>
Provides a rowset view over an XML document. For more information, see OPENXML (Transact-SQL).derived_table
Is a subquery that retrieves rows from the database. derived_table is used as input to the outer query.derived_table can use the Transact-SQL table value constructor feature to specify multiple rows. For example, SELECT * FROM (VALUES (1, 2), (3, 4), (5, 6), (7, 8), (9, 10) ) AS MyTable(a, b);. For more information, see Table Value Constructor (Transact-SQL).
column_alias
Is an optional alias to replace a column name in the result set of the derived table. Include one column alias for each column in the select list, and enclose the complete list of column aliases in parentheses.<tablesample_clause>
Specifies that a sample of data from the table is returned. The sample may be approximate. This clause can be used on any primary or joined table in a SELECT, UPDATE, or DELETE statement. TABLESAMPLE cannot be specified with views. For more information, see Limiting Result Sets by Using TABLESAMPLE.Note
When you use TABLESAMPLE against databases that are upgraded to SQL Server, the compatibility level of the database must be set to 90 or higher. To set the database compatibility level, see ALTER DATABASE Compatibility Level (Transact-SQL).
SYSTEM
Is an implementation-dependent sampling method specified by ISO standards. In SQL Server, this is the only sampling method available and is applied by default. SYSTEM applies a page-based sampling method in which a random set of pages from the table is chosen for the sample, and all the rows on those pages are returned as the sample subset. For more information, see Limiting Result Sets by Using TABLESAMPLE.sample_number
Is an exact or approximate constant numeric expression that represents the percent or number of rows. When specified with PERCENT, sample_number is implicitly converted to a float value; otherwise, it is converted to bigint. PERCENT is the default.PERCENT
Specifies that a sample_number percent of the rows of the table should be retrieved from the table. When PERCENT is specified, SQL Server returns an approximate of the percent specified. When PERCENT is specified the sample_number expression must evaluate to a value from 0 to 100.ROWS
Specifies that approximately sample_number of rows will be retrieved. When ROWS is specified, SQL Server returns an approximation of the number of rows specified. When ROWS is specified, the sample_number expression must evaluate to an integer value greater than zero.REPEATABLE
Indicates that the selected sample can be returned again. When specified with the same repeat_seed value, SQL Server will return the same subset of rows as long as no changes have been made to any rows in the table. When specified with a different repeat_seed value, SQL Server will likely return some different sample of the rows in the table. The following actions to the table are considered changes: insert, update, delete, index rebuild or defragmentation, and database restore or attach.repeat_seed
Is a constant integer expression used by SQL Server to generate a random number. repeat_seed is bigint. If repeat_seed is not specified, SQL Server assigns a value at random. For a specific repeat_seed value, the sampling result is always the same if no changes have been applied to the table. The repeat_seed expression must evaluate to an integer greater than zero.<joined_table>
Is a result set that is the product of two or more tables. For multiple joins, use parentheses to change the natural order of the joins.<join_type>
Specifies the type of join operation.INNER
Specifies all matching pairs of rows are returned. Discards unmatched rows from both tables. When no join type is specified, this is the default.FULL [ OUTER ]
Specifies that a row from either the left or right table that does not meet the join condition is included in the result set, and output columns that correspond to the other table are set to NULL. This is in addition to all rows typically returned by the INNER JOIN.LEFT [ OUTER ]
Specifies that all rows from the left table not meeting the join condition are included in the result set, and output columns from the other table are set to NULL in addition to all rows returned by the inner join.RIGHT [OUTER]
Specifies all rows from the right table not meeting the join condition are included in the result set, and output columns that correspond to the other table are set to NULL, in addition to all rows returned by the inner join.<join_hint>
Specifies that the SQL Server query optimizer use one join hint, or execution algorithm, per join specified in the query FROM clause. For more information, see Join Hints (Transact-SQL).JOIN
Indicates that the specified join operation should occur between the specified table sources or views.ON <search_condition>
Specifies the condition on which the join is based. The condition can specify any predicate, although columns and comparison operators are frequently used, for example:SELECT p.ProductID, v.VendorID FROM Production.Product AS p JOIN Purchasing.ProductVendor AS v ON (p.ProductID = v.ProductID);
When the condition specifies columns, the columns do not have to have the same name or same data type; however, if the data types are not the same, they must be either compatible or types that SQL Server can implicitly convert. If the data types cannot be implicitly converted, the condition must explicitly convert the data type by using the CONVERT function.
There can be predicates that involve only one of the joined tables in the ON clause. Such predicates also can be in the WHERE clause in the query. Although the placement of such predicates does not make a difference for INNER joins, they might cause a different result when OUTER joins are involved. This is because the predicates in the ON clause are applied to the table before the join, whereas the WHERE clause is semantically applied to the result of the join.
For more information about search conditions and predicates, see Search Condition (Transact-SQL).
CROSS JOIN
Specifies the cross-product of two tables. Returns the same rows as if no WHERE clause was specified in an old-style, non-SQL-92-style join.left_table_source{ CROSS | OUTER } APPLY right_table_source
Specifies that the right_table_source of the APPLY operator is evaluated against every row of the left_table_source. This functionality is useful when the right_table_source contains a table-valued function that takes column values from the left_table_source as one of its arguments.Either CROSS or OUTER must be specified with APPLY. When CROSS is specified, no rows are produced when the right_table_source is evaluated against a specified row of the left_table_source and returns an empty result set.
When OUTER is specified, one row is produced for each row of the left_table_source even when the right_table_source evaluates against that row and returns an empty result set.
For more information, see the Remarks section and Using APPLY.
left_table_source
Is a table source as defined in the previous argument. For more information, see the Remarks section.right_table_source
Is a table source as defined in the previous argument. For more information, see the Remarks section.table_source PIVOT <pivot_clause>
Specifies that the table_source is pivoted based on the pivot_column. table_source is a table or table expression. The output is a table that contains all columns of the table_source except the pivot_column and value_column. The columns of the table_source, except the pivot_column and value_column, are called the grouping columns of the pivot operator.PIVOT performs a grouping operation on the input table with regard to the grouping columns and returns one row for each group. Additionally, the output contains one column for each value specified in the column_list that appears in the pivot_column of the input_table.
For more information, see the Remarks section and Using PIVOT and UNPIVOT.
Note
When you use PIVOT against databases that are upgraded to SQL Server, the compatibility level of the database must be set to 90 or higher. For more information about setting the database compatibility level, see ALTER DATABASE Compatibility Level (Transact-SQL).
aggregate_function
Is a system or user-defined aggregate function that accepts one or more inputs. The aggregate function should be invariant to null values. An aggregate function invariant to null values does not consider null values in the group while it is evaluating the aggregate value.The COUNT(*) system aggregate function is not allowed.
value_column
Is the value column of the PIVOT operator. When used with UNPIVOT, value_column cannot be the name of an existing column in the input table_source.FOR pivot_column
Is the pivot column of the PIVOT operator. pivot_column must be of a type implicitly or explicitly convertible to nvarchar(). This column cannot be image or rowversion.When UNPIVOT is used, pivot_column is the name of the output column that becomes narrowed from the table_source. There cannot be an existing column in table_source with that name.
IN (column_list )
In the PIVOT clause, lists the values in the pivot_column that will become the column names of the output table. The list cannot specify any column names that already exist in the input table_source that is being pivoted.In the UNPIVOT clause, lists the columns in table_source that will be narrowed into a single pivot_column.
table_alias
Is the alias name of the output table. pivot_table_alias must be specified.UNPIVOT < unpivot_clause >
Specifies that the input table is narrowed from multiple columns in column_list into a single column called pivot_column.For more information, see the Remarks section and Using PIVOT and UNPIVOT.
Note
When you use UNPIVOT against databases that are upgraded to SQL Server, the compatibility level of the database must be set to 90 or higher. To set the database compatibility level, see ALTER DATABASE Compatibility Level (Transact-SQL).
Remarks
The FROM clause supports the SQL-92-SQL syntax for joined tables and derived tables. SQL-92 syntax provides the INNER, LEFT OUTER, RIGHT OUTER, FULL OUTER, and CROSS join operators.
UNION and JOIN within a FROM clause are supported within views and in derived tables and subqueries.
A self-join is a table that is joined to itself. Insert or update operations that are based on a self-join follow the order in the FROM clause.
Earlier versions of SQL Server support the definition of outer joins that use the *= and =* operators in the WHERE clause. SQL Server version 7.0 supports the ISO standard. This provides join operators in the FROM clause. When the compatibility level of the database is set to 90 or higher, the outer join operators (*= and =*) are not supported.
Because SQL Server considers distribution and cardinality statistics from linked servers that provide column distribution statistics, the REMOTE join hint is not required to force evaluating a join remotely. The SQL Server query processor considers remote statistics and determines whether a remote-join strategy is appropriate. REMOTE join hint is useful for providers that do not provide column distribution statistics. For more information, see Distribution Statistics Requirements for OLE DB Providers.
For more information about how to work with joins, see Join Fundamentals and Using Joins.
Using APPLY
Both the left and right operands of the APPLY operator are table expressions. The main difference between these operands is that the right_table_source can use a table-valued function that takes a column from the left_table_source as one of the arguments of the function. The left_table_source can include table-valued functions, but it cannot contain arguments that are columns from the right_table_source.
The APPLY operator works in the following way to produce the table source for the FROM clause:
Evaluates right_table_source against each row of the left_table_source to produce rowsets.
The values in the right_table_source depend on left_table_source. right_table_source can be represented approximately this way: TVF(left_table_source.row), where TVF is a table-valued function.
Combines the result sets that are produced for each row in the evaluation of right_table_source with the left_table_source by performing a UNION ALL operation.
The list of columns produced by the result of the APPLY operator is the set of columns from the left_table_source that is combined with the list of columns from the right_table_source.
Using PIVOT and UNPIVOT
The pivot_column and value_column are grouping columns that are used by the PIVOT operator. PIVOT follows the following process to obtain the output result set:
Performs a GROUP BY on its input_table against the grouping columns and produces one output row for each group.
The grouping columns in the output row obtain the corresponding column values for that group in the input_table.
Generates values for the columns in the column list for each output row by performing the following:
Grouping additionally the rows generated in the GROUP BY in the previous step against the pivot_column.
For each output column in the column_list, selecting a subgroup that satisfies the condition:
pivot_column = CONVERT(<data type of pivot_column>, 'output_column')
aggregate_function is evaluated against the value_column on this subgroup and its result is returned as the value of the corresponding output_column. If the subgroup is empty, SQL Server generates a null value for that output_column. If the aggregate function is COUNT and the subgroup is empty, zero (0) is returned.
For more information, see Using PIVOT and UNPIVOT.
Permissions
Requires the permissions for the DELETE, SELECT, or UPDATE statement.
Examples
A. Using a simple FROM clause
The following example retrieves the TerritoryID and Name columns from the SalesTerritory table in the AdventureWorks sample database.
USE AdventureWorks ;
GO
SELECT TerritoryID, Name
FROM Sales.SalesTerritory
ORDER BY TerritoryID ;
Here is the result set.
TerritoryID Name
----------- ------------------------------
1 Northwest
2 Northeast
3 Central
4 Southwest
5 Southeast
6 Canada
7 France
8 Germany
9 Australia
10 United Kingdom
(10 row(s) affected)
B. Using the TABLOCK and HOLDLOCK optimizer hints
The following partial transaction shows how to place an explicit shared table lock on Employee and how to read the index. The lock is held throughout the whole transaction.
USE AdventureWorks ;
GO
BEGIN TRAN
SELECT COUNT(*)
FROM HumanResources.Employee WITH (TABLOCK, HOLDLOCK) ;
C. Using the SQL-92 CROSS JOIN syntax
The following example returns the cross product of the two tables Employee and Department. A list of all possible combinations of EmployeeID rows and all Department name rows are returned.
USE AdventureWorks ;
GO
SELECT e.EmployeeID, d.Name AS Department
FROM HumanResources.Employee AS e
CROSS JOIN HumanResources.Department AS d
ORDER BY e.EmployeeID, d.Name ;
D. Using the SQL-92 FULL OUTER JOIN syntax
The following example returns the product name and any corresponding sales orders in the SalesOrderDetail table. It also returns any sales orders that have no product listed in the Product table, and any products with a sales order other than the one listed in the Product table.
USE AdventureWorks ;
GO
-- The OUTER keyword following the FULL keyword is optional.
SELECT p.Name, sod.SalesOrderID
FROM Production.Product AS p
FULL OUTER JOIN Sales.SalesOrderDetail AS sod
ON p.ProductID = sod.ProductID
WHERE p.ProductID IS NULL OR sod.ProductID IS NULL
ORDER BY p.Name ;
E. Using the SQL-92 LEFT OUTER JOIN syntax
The following example joins two tables on ProductID and preserves the unmatched rows from the left table. The Product table is matched with the SalesOrderDetail table on the ProductID columns in each table. All products, ordered and not ordered, appear in the result set.
USE AdventureWorks ;
GO
SELECT p.Name, sod.SalesOrderID
FROM Production.Product AS p
LEFT OUTER JOIN Sales.SalesOrderDetail AS sod
ON p.ProductID = sod.ProductID
ORDER BY p.Name ;
F. Using the SQL-92 INNER JOIN syntax
The following example returns all product names and sales order IDs.
USE AdventureWorks ;
GO
-- By default, SQL Server performs an INNER JOIN if only the JOIN
-- keyword is specified.
SELECT p.Name, sod.SalesOrderID
FROM Production.Product AS p
INNER JOIN Sales.SalesOrderDetail AS sod
ON p.ProductID = sod.ProductID
ORDER BY p.Name ;
G. Using the SQL-92 RIGHT OUTER JOIN syntax
The following example joins two tables on TerritoryID and preserves the unmatched rows from the right table. The SalesTerritory table is matched with the SalesPerson table on the TerritoryID column in each table. All salespersons appear in the result set, whether or not they are assigned a territory.
USE AdventureWorks ;
GO
SELECT st.Name AS Territory, sp.SalesPersonID
FROM Sales.SalesTerritory AS st
RIGHT OUTER JOIN Sales.SalesPerson AS sp
ON st.TerritoryID = sp.TerritoryID ;
H. Using HASH and MERGE join hints
The following example performs a three-table join among the Product, ProductVendor, and Vendor tables to produce a list of products and their vendors. The query optimizer joins Product and ProductVendor (p and pv) by using a MERGE join. Next, the results of the Product and ProductVendor MERGE join (p and pv) are HASH joined to the Vendor table to produce (p and pv) and v.
Important
After a join hint is specified, the INNER keyword is no longer optional and must be explicitly stated for an INNER JOIN to be performed.
USE AdventureWorks ;
GO
SELECT p.Name AS ProductName, v.Name AS VendorName
FROM Production.Product AS p
INNER MERGE JOIN Purchasing.ProductVendor AS pv
ON p.ProductID = pv.ProductID
INNER HASH JOIN Purchasing.Vendor AS v
ON pv.VendorID = v.VendorID
ORDER BY p.Name, v.Name ;
I. Using a derived table
The following example uses a derived table, a SELECT statement after the FROM clause, to return the first and last names of all employees and the cities in which they live.
USE AdventureWorks ;
GO
SELECT RTRIM(c.FirstName) + ' ' + LTRIM(c.LastName) AS Name,
d.City
FROM Person.Contact AS c
INNER JOIN HumanResources.Employee e ON c.ContactID = e.ContactID
INNER JOIN
(SELECT ea.AddressID, ea.EmployeeID, a.City
FROM Person.Address AS a
INNER JOIN HumanResources.EmployeeAddress AS ea
ON a.AddressID = ea.AddressID) AS d
ON e.EmployeeID = d.EmployeeID
ORDER BY c.LastName, c.FirstName;
J. Using TABLESAMPLE to read data from a sample of rows in a table
The following example uses TABLESAMPLE in the FROM clause to return approximately 10 percent of all the rows in the Customer table in the AdventureWorks database.
USE AdventureWorks ;
GO
SELECT *
FROM Sales.Customer TABLESAMPLE SYSTEM (10 PERCENT) ;
K. Using APPLY
The following example assumes that the following tables with the following schema exist in the database:
Departments: DeptID, DivisionID, DeptName, DeptMgrID
EmpMgr: MgrID, EmpID
Employees: EmpID, EmpLastName, EmpFirstName, EmpSalary
There is also a table-valued function, GetReports(MgrID) that returns the list of all employees (EmpID, EmpLastName, EmpSalary) that report directly or indirectly to the specified MgrID.
The example uses APPLY to return all departments and all employees in that department. If a particular department does not have any employees, there will not be any rows returned for that department.
SELECT DeptID, DeptName, DeptMgrID, EmpID, EmpLastName, EmpSalary
FROM Departments d CROSS APPLY dbo.GetReports(d.DeptMgrID) ;
If you want the query to produce rows for those departments without employees, which will produce null values for the EmpID, EmpLastName and EmpSalary columns, use OUTER APPLY instead.
SELECT DeptID, DeptName, DeptMgrID, EmpID, EmpLastName, EmpSalary
FROM Departments d OUTER APPLY dbo.GetReports(d.DeptMgrID) ;
L. Using PIVOT and UNPIVOT
The following example returns the number of purchase orders placed by employee IDs 164, 198, 223, 231, and 233, categorized by vendor ID.
USE AdventureWorks;
GO
SELECT VendorID, [164] AS Emp1, [198] AS Emp2, [223] AS Emp3, [231] AS Emp4, [233] AS Emp5
FROM
(SELECT PurchaseOrderID, EmployeeID, VendorID
FROM Purchasing.PurchaseOrderHeader) AS p
PIVOT
(
COUNT (PurchaseOrderID)
FOR EmployeeID IN
( [164], [198], [223], [231], [233] )
) AS pvt
ORDER BY VendorID;
Here is a partial result set:
VendorID Emp1 Emp2 Emp3 Emp4 Emp5
----------------------------------------------------------------
1 4 3 5 4 4
2 4 1 5 5 5
3 4 3 5 4 4
4 4 2 5 5 4
5 5 1 5 5 5
To unpivot the table, assume the result set produced in the previous example is stored as pvt. The query looks like the following.
--Create the table and insert values as portrayed in the previous example.
CREATE TABLE dbo.pvt (VendorID int, Emp1 int, Emp2 int,
Emp3 int, Emp4 int, Emp5 int);
GO
-- Insert 5 rows into the table.
INSERT INTO dbo.pvt VALUES (1,4,3,5,4,4),(2,4,1,5,5,5),(3,4,3,5,4,4),
(4,4,2,5,5,4),(5,5,1,5,5,5);
GO
--Unpivot the table.
SELECT VendorID, Employee, Orders
FROM
(SELECT VendorID, Emp1, Emp2, Emp3, Emp4, Emp5
FROM dbo.pvt) AS p
UNPIVOT
(Orders FOR Employee IN
(Emp1, Emp2, Emp3, Emp4, Emp5)
)AS unpvt;
GO
Here is a partial result set:
VendorID Employee Orders
------------------------------
1 Emp1 4
1 Emp2 3
1 Emp3 5
1 Emp4 4
1 Emp5 4
2 Emp1 4
2 Emp2 1
2 Emp3 5
2 Emp4 5
2 Emp5 5