MIN (Transact-SQL)
Applies to: SQL Server Azure SQL Database Azure SQL Managed Instance Azure Synapse Analytics Analytics Platform System (PDW) SQL analytics endpoint in Microsoft Fabric Warehouse in Microsoft Fabric
Returns the minimum value in the expression. May be followed by the OVER clause.
Transact-SQL syntax conventions
Syntax
-- Aggregation Function Syntax
MIN ( [ ALL | DISTINCT ] expression )
-- Analytic Function Syntax
MIN ( [ ALL ] expression ) OVER ( [ <partition_by_clause> ] [ <order_by_clause> ] )
Arguments
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 MIN and is available for ISO compatibility only.
expression
Is a constant, column name, or function, and any combination of arithmetic, bitwise, and string operators. MIN can be used with numeric, char, varchar, uniqueidentifier, or 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).
Return Types
Returns a value same as expression.
Remarks
MIN ignores any null values.
With character data columns, MIN finds the value that is lowest in the sort sequence.
MIN 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.
Examples
A. Simple example
The following example returns the lowest (minimum) tax rate. The example uses the AdventureWorks2022 database
SELECT MIN(TaxRate)
FROM Sales.SalesTaxRate;
GO
Here's the result set.
-------------------
5.00
(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 AdventureWorks2022 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's 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)
Examples: Azure Synapse Analytics and Analytics Platform System (PDW)
C. Using MIN
The following example uses the MIN aggregate function to return the price of the least expensive (minimum) product in a specified set of sales orders.
-- Uses AdventureWorks
SELECT DISTINCT MIN(UnitPrice)
FROM dbo.FactResellerSales
WHERE SalesOrderNumber IN (N'SO43659', N'SO43660', N'SO43664');
Here's the result set.
------
5.1865
D. Using MIN with OVER
The following examples use the MIN OVER() analytic function to return the price of the least expensive product in each sales order. The result set is partitioned by the SalesOrderID
column.
-- Uses AdventureWorks
SELECT DISTINCT MIN(UnitPrice) OVER(PARTITION BY SalesOrderNumber) AS LeastExpensiveProduct,
SalesOrderNumber
FROM dbo.FactResellerSales
WHERE SalesOrderNumber IN (N'SO43659', N'SO43660', N'SO43664')
ORDER BY SalesOrderNumber;
Here's the result set.
LeastExpensiveProduct SalesOrderID
--------------------- ----------
5.1865 SO43659
419.4589 SO43660
28.8404 SO43664
See Also
Aggregate Functions (Transact-SQL)
MAX (Transact-SQL)
OVER Clause (Transact-SQL)