\n
We are excited to announce that the GREATEST and LEAST T-SQL functions are now generally available in Azure SQL Database, as well as in Azure Synapse Analytics (serverless SQL pools only) and Azure SQL Managed Instance.
\n
The functions will also be available in upcoming releases of SQL Server.
\n
This post describes the functionality and common use cases of GREATEST and LEAST in Azure SQL Database, as well as how they can provide a more concise and efficient solution for developers compared to existing T-SQL alternatives.
\n
\n\n
\n
GREATEST and LEAST are scalar-valued functions and return the maximum and minimum value, respectively, of a list of one or more expressions.
\n
\n
The syntax is as follows:
\n
GREATEST ( expression1 [ ,...expressionN ] )\nLEAST ( expression1 [ ,...expressionN ] )
\n
\n
As an example, let’s say we have a table CustomerAccounts and wish to return the maximum account balance for each customer:
\n
\n
\n\n\nCustomerID | \nChecking | \nSavings | \nBrokerage | \n
\n\n1001 | \n$ 4,294.10 | \n$ 14,109.84 | \n$ 3,000.01 | \n
\n\n1002 | \n$ 51,495.00 | \n$ 97,103.43 | \n$ 0.02 | \n
\n\n1003 | \n$ 10,619.73 | \n$ 33,194.01 | \n$ 5,005.74 | \n
\n\n1004 | \n$ 24,924.33 | \n$ 203,100.52 | \n$ 10,866.87 | \n
\n\n
\n
\n
Prior to GREATEST and LEAST, we could achieve this through a searched CASE expression:
\n
SELECT CustomerID, GreatestBalance =\n CASE\n WHEN Checking >= Savings and Checking >= Brokerage THEN Checking\n WHEN Savings > Checking and Savings > Brokerage THEN Savings\n WHEN Brokerage > Checking and Brokerage > Savings THEN Brokerage\n END\nFROM CustomerAccounts;
\n
\n
We could alternatively use CROSS APPLY:
\n
SELECT ca.CustomerID, MAX(T.Balance) as GreatestBalance\nFROM CustomerAccounts as ca\nCROSS APPLY (VALUES (ca.Checking),(ca.Savings),(ca.Brokerage)) AS T(Balance)\nGROUP BY ca.CustomerID;
\n
\n
Other valid approaches include user-defined functions (UDFs) and subqueries with aggregates.
\n
However, as the number of columns or expressions increases, so does the tedium of constructing these queries and the lack of readability and maintainability.
\n
\n
With GREATEST, we can return the same results as the queries above with the following syntax:
\n
SELECT CustomerID, GREATEST(Checking, Savings, Brokerage) AS GreatestBalance \nFROM CustomerAccounts;
\n
\n
Here is the result set:
\n
CustomerID GreatestBalance\n----------- ---------------------\n1001 14109.84\n1002 97103.43\n1003 33194.01\n1004 203100.52\n\n(4 rows affected)
\n
\n
Similarly, if you previously wished to return a value that’s capped by a certain amount, you would need to write a statement such as:
\n
DECLARE @Val INT = 75;\nDECLARE @Cap INT = 50;\nSELECT CASE WHEN @Val > @Cap THEN @Cap ELSE @Val END as CappedAmt;
\n
\n
With LEAST, you can achieve the same result with:
\n
DECLARE @Val INT = 75;\nDECLARE @Cap INT = 50;\nSELECT LEAST(@Val, @Cap) as CappedAmt;
\n
\n
The syntax for an increasing number of expressions is vastly simpler and more concise with GREATEST and LEAST than with the manual alternatives mentioned above
\n
As such, these functions allow developers to be more productive by avoiding the need to construct lengthy statements to simply find the maximum or minimum value in an expression list.
\n\n\n
\n\n
One of the simpler use cases for GREATEST and LEAST is determining the maximum or minimum value from a list of constants:
\n
SELECT LEAST ( '6.62', 33.1415, N'7' ) AS LeastVal;
\n
\n
Here is the result set. Note that the return type scale is determined by the scale of the highest precedence argument, in this case float.
\n
LeastVal\n--------\n6.6200\n\n(1 rows affected)
\n\n\n
\n
Perhaps we wish to compare column values in a WHERE clause predicate against the maximum value of two local variables:
\n
CREATE TABLE dbo.studies (\n VarX varchar(10) NOT NULL,\n Correlation decimal(4, 3) NULL\n);\n\nINSERT INTO dbo.studies VALUES ('Var1', 0.2), ('Var2', 0.825), ('Var3', 0.61);\nGO\n\nDECLARE @PredictionA DECIMAL(2,1) = 0.7;\nDECLARE @PredictionB DECIMAL(3,2) = 0.65;\n\nSELECT VarX, Correlation\nFROM dbo.studies\nWHERE Correlation > GREATEST(@PredictionA, @PredictionB);\nGO
\n
\n
Here is the result set:
\n
VarX Correlation\n---------- -----------\nVar2 .825\n\n(1 rows affected)
\n\n\n
\n
At times we may want to compare columns, constants and variables together. Here is one such example using LEAST:
\n
CREATE TABLE dbo.products (\n prod_id INT IDENTITY(1,1),\n listprice smallmoney NULL\n);\n\nINSERT INTO dbo.products VALUES (14.99), (49.99), (24.99);\nGO\n\nDECLARE @PriceX smallmoney = 19.99;\n\nSELECT LEAST(listprice, 40, @PriceX) as LeastPrice\nFROM dbo.products;\nGO
\n
\n
And the result set:
\n
LeastPrice\n------------\n 14.99\n 19.99\n 19.99
\n\n\n
\n
GREATEST and LEAST provide a concise way to determine the maximum and minimum value, respectively, of a list of expressions.
\n
For full documentation of the functions, see GREATEST (Transact-SQL) - SQL Server | Microsoft Docs and LEAST (Transact-SQL) - SQL Server | Microsoft Docs.
\n
These new T-SQL functions will increase your productivity and enhance your experience with Azure Synapse Analytics, Azure SQL Database, and Azure SQL Managed Instance.
\n
\n
Providing the GREATEST developer experience in Azure is the LEAST we can do.
\n
\n
John Steen, Software Engineer
Austin SQL Team
\n
","body@stringLength":"12964","rawBody":"\n
We are excited to announce that the GREATEST and LEAST T-SQL functions are now generally available in Azure SQL Database, as well as in Azure Synapse Analytics (serverless SQL pools only) and Azure SQL Managed Instance.
\n
The functions will also be available in upcoming releases of SQL Server.
\n
This post describes the functionality and common use cases of GREATEST and LEAST in Azure SQL Database, as well as how they can provide a more concise and efficient solution for developers compared to existing T-SQL alternatives.
\n
\n
Functionality
\n
\n
GREATEST and LEAST are scalar-valued functions and return the maximum and minimum value, respectively, of a list of one or more expressions.
\n
\n
The syntax is as follows:
\n
GREATEST ( expression1 [ ,...expressionN ] )\nLEAST ( expression1 [ ,...expressionN ] )\n
\n
As an example, let’s say we have a table CustomerAccounts and wish to return the maximum account balance for each customer:
\n
\n
\n\n\nCustomerID | \nChecking | \nSavings | \nBrokerage | \n
\n\n1001 | \n$ 4,294.10 | \n$ 14,109.84 | \n$ 3,000.01 | \n
\n\n1002 | \n$ 51,495.00 | \n$ 97,103.43 | \n$ 0.02 | \n
\n\n1003 | \n$ 10,619.73 | \n$ 33,194.01 | \n$ 5,005.74 | \n
\n\n1004 | \n$ 24,924.33 | \n$ 203,100.52 | \n$ 10,866.87 | \n
\n\n
\n
\n
Prior to GREATEST and LEAST, we could achieve this through a searched CASE expression:
\n
SELECT CustomerID, GreatestBalance =\n CASE\n WHEN Checking >= Savings and Checking >= Brokerage THEN Checking\n WHEN Savings > Checking and Savings > Brokerage THEN Savings\n WHEN Brokerage > Checking and Brokerage > Savings THEN Brokerage\n END\nFROM CustomerAccounts;\n
\n
We could alternatively use CROSS APPLY:
\n
SELECT ca.CustomerID, MAX(T.Balance) as GreatestBalance\nFROM CustomerAccounts as ca\nCROSS APPLY (VALUES (ca.Checking),(ca.Savings),(ca.Brokerage)) AS T(Balance)\nGROUP BY ca.CustomerID;\n
\n
Other valid approaches include user-defined functions (UDFs) and subqueries with aggregates.
\n
However, as the number of columns or expressions increases, so does the tedium of constructing these queries and the lack of readability and maintainability.
\n
\n
With GREATEST, we can return the same results as the queries above with the following syntax:
\n
SELECT CustomerID, GREATEST(Checking, Savings, Brokerage) AS GreatestBalance \nFROM CustomerAccounts;\n
\n
Here is the result set:
\n
CustomerID GreatestBalance\n----------- ---------------------\n1001 14109.84\n1002 97103.43\n1003 33194.01\n1004 203100.52\n\n(4 rows affected)\n
\n
Similarly, if you previously wished to return a value that’s capped by a certain amount, you would need to write a statement such as:
\n
DECLARE @Val INT = 75;\nDECLARE @Cap INT = 50;\nSELECT CASE WHEN @Val > @Cap THEN @Cap ELSE @Val END as CappedAmt;\n
\n
With LEAST, you can achieve the same result with:
\n
DECLARE @Val INT = 75;\nDECLARE @Cap INT = 50;\nSELECT LEAST(@Val, @Cap) as CappedAmt;\n
\n
The syntax for an increasing number of expressions is vastly simpler and more concise with GREATEST and LEAST than with the manual alternatives mentioned above
\n
As such, these functions allow developers to be more productive by avoiding the need to construct lengthy statements to simply find the maximum or minimum value in an expression list.
\n
\n
Common use cases
\n
\n
Constant arguments
\n
One of the simpler use cases for GREATEST and LEAST is determining the maximum or minimum value from a list of constants:
\n
SELECT LEAST ( '6.62', 33.1415, N'7' ) AS LeastVal;\n
\n
Here is the result set. Note that the return type scale is determined by the scale of the highest precedence argument, in this case float.
\n
LeastVal\n--------\n6.6200\n\n(1 rows affected)\n
\n
Local variables
\n
\n
Perhaps we wish to compare column values in a WHERE clause predicate against the maximum value of two local variables:
\n
CREATE TABLE dbo.studies (\n VarX varchar(10) NOT NULL,\n Correlation decimal(4, 3) NULL\n);\n\nINSERT INTO dbo.studies VALUES ('Var1', 0.2), ('Var2', 0.825), ('Var3', 0.61);\nGO\n\nDECLARE @PredictionA DECIMAL(2,1) = 0.7;\nDECLARE @PredictionB DECIMAL(3,2) = 0.65;\n\nSELECT VarX, Correlation\nFROM dbo.studies\nWHERE Correlation > GREATEST(@PredictionA, @PredictionB);\nGO\n
\n
Here is the result set:
\n
VarX Correlation\n---------- -----------\nVar2 .825\n\n(1 rows affected)\n
\n
Columns, constants and variables
\n
\n
At times we may want to compare columns, constants and variables together. Here is one such example using LEAST:
\n
CREATE TABLE dbo.products (\n prod_id INT IDENTITY(1,1),\n listprice smallmoney NULL\n);\n\nINSERT INTO dbo.products VALUES (14.99), (49.99), (24.99);\nGO\n\nDECLARE @PriceX smallmoney = 19.99;\n\nSELECT LEAST(listprice, 40, @PriceX) as LeastPrice\nFROM dbo.products;\nGO\n
\n
And the result set:
\n
LeastPrice\n------------\n 14.99\n 19.99\n 19.99\n
\n
Summary
\n
\n
GREATEST and LEAST provide a concise way to determine the maximum and minimum value, respectively, of a list of expressions.
\n
For full documentation of the functions, see GREATEST (Transact-SQL) - SQL Server | Microsoft Docs and LEAST (Transact-SQL) - SQL Server | Microsoft Docs.
\n
These new T-SQL functions will increase your productivity and enhance your experience with Azure Synapse Analytics, Azure SQL Database, and Azure SQL Managed Instance.
\n
\n
Providing the GREATEST developer experience in Azure is the LEAST we can do.
\n
\n
John Steen, Software Engineer
Austin SQL Team
\n
","kudosSumWeight":2,"postTime":"2021-04-22T14:57:36.139-07:00","images":{"__typename":"AssociatedImageConnection","edges":[{"__typename":"AssociatedImageEdge","cursor":"MjUuMXwyLjF8b3wyNXxfTlZffDE","node":{"__ref":"AssociatedImage:{\"url\":\"https://techcommunity.microsoft.com/t5/s/gxcuf89792/images/bS0yMjgxNzI2LTI3NDgyMGlGNDBCMTM5ODZGOTYyRTc1?revision=5\"}"}}],"totalCount":1,"pageInfo":{"__typename":"PageInfo","hasNextPage":false,"endCursor":null,"hasPreviousPage":false,"startCursor":null}},"attachments":{"__typename":"AttachmentConnection","pageInfo":{"__typename":"PageInfo","hasNextPage":false,"endCursor":null,"hasPreviousPage":false,"startCursor":null},"edges":[]},"tags":{"__typename":"TagConnection","pageInfo":{"__typename":"PageInfo","hasNextPage":false,"endCursor":null,"hasPreviousPage":false,"startCursor":null},"edges":[{"__typename":"TagEdge","cursor":"MjUuMXwyLjF8b3wxMHxfTlZffDE","node":{"__typename":"Tag","id":"tag:azure sql","text":"azure sql","time":"2018-12-05T17:15:03.966-08:00","lastActivityTime":null,"messagesCount":null,"followersCount":null}},{"__typename":"TagEdge","cursor":"MjUuMXwyLjF8b3wxMHxfTlZffDI","node":{"__typename":"Tag","id":"tag:azure sql database","text":"azure sql database","time":"2017-08-22T12:33:06.546-07:00","lastActivityTime":null,"messagesCount":null,"followersCount":null}}]},"timeToRead":4,"rawTeaser":"...
...
But in MySQL it comes out of the box and it's a shame we have to put it in the SELECT for Azure SQL Database
","body@stripHtml({\"removeProcessingText\":false,\"removeSpoilerMarkup\":false,\"removeTocMarkup\":false,\"truncateLength\":200})@stringLength":"233","kudosSumWeight":0,"repliesCount":0,"postTime":"2023-12-01T05:04:13.690-08:00","lastPublishTime":"2023-12-01T05:04:13.690-08:00","metrics":{"__typename":"MessageMetrics","views":2727},"visibilityScope":"PUBLIC","placeholder":false,"originalMessageForPlaceholder":null,"entityType":"BLOG_REPLY","eventPath":"category:AzureDatabases/category:products-services/category:communities/community:gxcuf89792board:AzureSQLBlog/message:2281726/message:3998254","replies":{"__typename":"MessageConnection","pageInfo":{"__typename":"PageInfo","hasNextPage":false,"endCursor":null,"hasPreviousPage":false,"startCursor":null},"edges":[]},"customFields":[],"attachments":{"__typename":"AttachmentConnection","edges":[],"pageInfo":{"__typename":"PageInfo","hasNextPage":false,"endCursor":null,"hasPreviousPage":false,"startCursor":null}}},"Rank:rank:37":{"__typename":"Rank","id":"rank:37","position":18,"name":"Copper Contributor","color":"333333","icon":null,"rankStyle":"TEXT"},"User:user:1276878":{"__typename":"User","id":"user:1276878","uid":1276878,"login":"Sandip_Mehta","biography":null,"registrationData":{"__typename":"RegistrationData","status":null,"registrationTime":"2022-01-15T15:05:34.444-08:00"},"deleted":false,"email":"","avatar":{"__typename":"UserAvatar","url":"https://techcommunity.microsoft.com/t5/s/gxcuf89792/m_assets/avatars/default/avatar-6.svg?time=0"},"rank":{"__ref":"Rank:rank:37"},"entityType":"USER","eventPath":"community:gxcuf89792/user:1276878"},"ModerationData:moderation_data:3140316":{"__typename":"ModerationData","id":"moderation_data:3140316","status":"APPROVED","rejectReason":null,"isReportedAbuse":false,"rejectUser":null,"rejectTime":null,"rejectActorType":null},"BlogReplyMessage:message:3140316":{"__typename":"BlogReplyMessage","author":{"__ref":"User:user:1276878"},"id":"message:3140316","revisionNum":1,"uid":3140316,"depth":1,"hasGivenKudo":false,"subscribed":false,"board":{"__ref":"Blog:board:AzureSQLBlog"},"parent":{"__ref":"BlogTopicMessage:message:2281726"},"conversation":{"__ref":"Conversation:conversation:2281726"},"subject":"Re: Introducing the GREATEST and LEAST T-SQL functions","moderationData":{"__ref":"ModerationData:moderation_data:3140316"},"body":"The introduction of these new t-sql functions is a lifesaver. We had to jump through hoops to overcome their omission. Sometimes, we hardcoded this logic using \"case when\" when performance is critical and other times we used Clr functions for readability. But, all approaches were inelegant and had many limitations such as Clr functions only allowing a fixed number of parameters and data type specific implementations.
Btw, there is a further need for other t-sql functions to be added; at least to match what Oracle has to offer.
We can provide a list of functions we think would be very helpful additions.