MAX (Transact-SQL)

MAX (Transact-SQL)

 

THIS TOPIC APPLIES TO: yesSQL Server (starting with 2008)yesAzure SQL DatabaseyesAzure SQL Data Warehouse yesParallel Data Warehouse

Returns the maximum value in the expression.

Topic link icon Transact-SQL Syntax Conventions

  
MAX ( [ ALL | DISTINCT ] expression )  
   OVER ( [ partition_by_clause ] order_by_clause )     

-- Azure SQL Data Warehouse and Parallel Data Warehouse  
-- Aggregation Function Syntax  
MAX ( [ ALL | DISTINCT ] expression )  

-- Azure SQL Data Warehouse and Parallel Data Warehouse  
-- Aggregation Function Syntax   
MAX ( expression ) OVER ( [ <partition_by_clause> ] [ <order_by_clause> ] )  

ALL
Applies the aggregate function to all values. ALL is the default.

DISTINCT
Specifies that each unique value is considered. DISTINCT is not meaningful with MAX and is available for ISO compatibility only.

expression
Is a constant, column name, or function, and any combination of arithmetic, bitwise, and string operators. MAX can be used with numeric, character, uniqueidentifier, and datetime columns, but not with bit columns. Aggregate functions and subqueries are not permitted.

For more information, see Expressions (Transact-SQL).

OVER ( [ partition_by_clause ] order_by_clause)
partition_by_clause divides the result set produced by the FROM clause into partitions to which the function is applied. If not specified, the function treats all rows of the query result set as a single group. order_by_clause determines the logical order in which the operation is performed. order_by_clause is required. For more information, see OVER Clause (Transact-SQL).

Returns a value same as expression.

MAX ignores any null values.

For character columns, MAX finds the highest value in the collating sequence.

MAX is a deterministic function when used without the OVER and ORDER BY clauses. It is nondeterministic when specified with the OVER and ORDER BY clauses. For more information, see Deterministic and Nondeterministic Functions.

A. Simple example

The following example returns the highest (maximum) tax rate in the AdventureWorks2012 database.

SELECT MAX(TaxRate)  
FROM Sales.SalesTaxRate;  
GO  

Here is the result set.

-------------------

19.60

Warning, null value eliminated from aggregate.

(1 row(s) affected)

B. Using the OVER clause

The following example uses the MIN, MAX, AVG and COUNT functions with the OVER clause to provide aggregated values for each department in the HumanResources.Department table in the AdventureWorks2012 database.

SELECT DISTINCT Name  
       , MIN(Rate) OVER (PARTITION BY edh.DepartmentID) AS MinSalary  
       , MAX(Rate) OVER (PARTITION BY edh.DepartmentID) AS MaxSalary  
       , AVG(Rate) OVER (PARTITION BY edh.DepartmentID) AS AvgSalary  
       ,COUNT(edh.BusinessEntityID) OVER (PARTITION BY edh.DepartmentID) AS EmployeesPerDept  
FROM HumanResources.EmployeePayHistory AS eph  
JOIN HumanResources.EmployeeDepartmentHistory AS edh  
     ON eph.BusinessEntityID = edh.BusinessEntityID  
JOIN HumanResources.Department AS d  
 ON d.DepartmentID = edh.DepartmentID  
WHERE edh.EndDate IS NULL  
ORDER BY Name;  

Here is the result set.

Name                          MinSalary             MaxSalary             AvgSalary             EmployeesPerDept  
----------------------------- --------------------- --------------------- --------------------- ----------------  
Document Control              10.25                 17.7885               14.3884               5  
Engineering                   32.6923               63.4615               40.1442               6  
Executive                     39.06                 125.50                68.3034               4  
Facilities and Maintenance    9.25                  24.0385               13.0316               7  
Finance                       13.4615               43.2692               23.935                10  
Human Resources               13.9423               27.1394               18.0248               6  
Information Services          27.4038               50.4808               34.1586               10  
Marketing                     13.4615               37.50                 18.4318               11  
Production                    6.50                  84.1346               13.5537               195  
Production Control            8.62                  24.5192               16.7746               8  
Purchasing                    9.86                  30.00                 18.0202               14  
Quality Assurance             10.5769               28.8462               15.4647               6  
Research and Development      40.8654               50.4808               43.6731               4  
Sales                         23.0769               72.1154               29.9719               18  
Shipping and Receiving        9.00                  19.2308               10.8718               6  
Tool Design                   8.62                  29.8462               23.5054               6  
  
 (16 row(s) affected)  

C. Using MAX

The following example uses the MAX aggregate function to return the price of the most expensive (maximum) product in a specified set of sales orders.

-- Uses AdventureWorks  
  
SELECT DISTINCT MAX(UnitPrice)   
FROM dbo.FactResellerSales   
WHERE SalesOrderNumber IN (N'SO43659', N'SO43660', N'SO43664');  

Here is the result set.

----------

2039.9940

D. Using MAX with OVER

The following examples use the MAX OVER() analytic function to return the price of the most expensive product in each sales order.

-- Uses AdventureWorks  
  
SELECT DISTINCT MAX(UnitPrice) OVER(PARTITION BY SalesOrderNumber) AS MostExpensiveProduct,  
       SalesOrderNumber  
FROM dbo.FactResellerSales    
WHERE SalesOrderNumber IN (N'SO43659', N'SO43660', N'SO43664')  
ORDER BY SalesOrderNumber  
;  
  

Here is the result set.

MostExpensiveProduct SalesOrderNumber

--------------------- ----------------

2039.9940 SO43659

879.7940 SO43660

2039.9940 SO43664

Aggregate Functions (Transact-SQL)
OVER Clause (Transact-SQL)

Community Additions

ADD
Show:
© 2016 Microsoft