Loading learning content...
In mathematics, a function has a simple, powerful property: given the same inputs, it always produces the same output. The function f(x) = x² will forever return 4 when given 2, 9 when given 3, and 16 when given 4. This property—determinism—is so fundamental to mathematics that it's part of the definition of what a function is.
In database systems, deterministic functions carry this same guarantee. A deterministic function produces identical results every time it's called with identical arguments, regardless of when it's called, who calls it, or what state the database is in. This seemingly simple property unlocks profound optimizations and capabilities that non-deterministic functions cannot access.
Understanding determinism is essential because it determines:
By the end of this page, you will understand what makes a function deterministic or non-deterministic, learn how to verify and declare determinism across database platforms, explore the optimizer advantages deterministic functions enable, and develop strategies for designing functions with predictable behavior.
A function is deterministic if and only if it satisfies this invariant:
For any combination of input parameter values, the function always returns the exact same result.
This definition has subtle but important implications. "Always" means across time, across database sessions, across server restarts, and across different execution contexts. If any factor besides the input parameters can influence the output, the function is non-deterministic.
Let's crystallize this with concrete examples:
ABS(x), POWER(x, y), SQRT(x)UPPER(s), SUBSTRING(s, i, n), LEN(s)DATEDIFF(d1, d2), DATEADD(part, n, d)CAST(x AS INT), CONVERT(type, x)CalculateCompoundInterest(p, r, t)GETDATE(), CURRENT_TIMESTAMP, SYSDATETIME()RAND(), NEWID(), NEWSEQUENTIALID()@@SPID, USER_NAME(), SYSTEM_USERHOST_NAME(), APP_NAME()A function that calls ANY non-deterministic function becomes non-deterministic itself, even if that call is buried deep in nested function calls. A function that uses GETDATE() to timestamp a log entry—even in an IF branch that's rarely executed—is non-deterministic for its entire existence.
Determinism isn't just a theoretical property—it directly controls what capabilities are available to your functions. Database systems leverage determinism guarantees to enable powerful features that would be unsafe or incorrect with non-deterministic functions.
| Capability | Why Determinism Required | Impact If Non-Deterministic |
|---|---|---|
| Indexed Views | Index data must match underlying data; if function result changes, index becomes invalid | Cannot create indexed view referencing the function |
| Persisted Computed Columns | Stored value must equal computed value on every read; non-determinism breaks this | Computed column must be virtual (computed on access) |
| Index on Computed Column | Index key must be stable; changing values corrupt B-tree structure | Cannot create index on the computed column |
| Result Caching | Optimizer can reuse result only if guaranteed unchanged for same inputs | Function re-evaluated on every reference, even in same query |
| Parallel Execution | Parallel workers must produce consistent results independently | May be restricted to serial execution |
| CHECK Constraints | Constraint evaluation must be consistent; non-determinism causes random failures | Some systems reject non-deterministic functions in constraints |
1234567891011121314151617181920212223242526272829303132333435363738394041424344
-- Demonstration: Determinism enables advanced features -- DETERMINISTIC functionCREATE FUNCTION dbo.NormalizeSSN(@SSN VARCHAR(20))RETURNS CHAR(9)WITH SCHEMABINDING -- Schema binding helps establish determinismASBEGIN RETURN REPLACE(REPLACE(@SSN, '-', ''), ' ', '');END;GO -- Verify determinismSELECT OBJECTPROPERTY(OBJECT_ID('dbo.NormalizeSSN'), 'IsDeterministic') AS IsDeterministic;-- Returns 1 -- NOW we can create a PERSISTED computed columnALTER TABLE EmployeesADD SSN_Normalized AS dbo.NormalizeSSN(SSN) PERSISTED; -- AND we can INDEX it for fast lookupsCREATE INDEX IX_Employees_SSN_Normalized ON Employees(SSN_Normalized); -- NON-DETERMINISTIC functionCREATE FUNCTION dbo.GetAgeDynamic(@BirthDate DATE)RETURNS INTASBEGIN RETURN DATEDIFF(YEAR, @BirthDate, GETDATE()) - CASE WHEN DATEADD(YEAR, DATEDIFF(YEAR, @BirthDate, GETDATE()), @BirthDate) > GETDATE() THEN 1 ELSE 0 END;END;GO -- Verify determinismSELECT OBJECTPROPERTY(OBJECT_ID('dbo.GetAgeDynamic'), 'IsDeterministic') AS IsDeterministic;-- Returns 0 -- This FAILS: cannot persist non-deterministic computed column-- ALTER TABLE Employees ADD Age AS dbo.GetAgeDynamic(BirthDate) PERSISTED;-- Error: Computed column 'Age' cannot be persisted because the column is non-deterministic. -- Virtual computed column is allowed (computed on each access)ALTER TABLE Employees ADD Age AS dbo.GetAgeDynamic(BirthDate);Each database platform provides mechanisms to check whether a function is deterministic. Understanding how to query this information helps you validate function properties and troubleshoot when expected capabilities aren't available.
123456789101112131415161718192021222324252627282930313233343536373839
-- SQL Server: Check determinism using OBJECTPROPERTY -- Single function checkSELECT OBJECT_NAME(object_id) AS FunctionName, OBJECTPROPERTY(object_id, 'IsDeterministic') AS IsDeterministic, OBJECTPROPERTY(object_id, 'IsSchemaBound') AS IsSchemaBound, OBJECTPROPERTY(object_id, 'IsInlineFunction') AS IsInlinedFROM sys.objectsWHERE object_id = OBJECT_ID('dbo.MyFunction'); -- All user-defined functions with determinism statusSELECT SCHEMA_NAME(schema_id) AS SchemaName, name AS FunctionName, type_desc AS FunctionType, OBJECTPROPERTY(object_id, 'IsDeterministic') AS IsDeterministic, OBJECTPROPERTY(object_id, 'IsSchemaBound') AS IsSchemaBoundFROM sys.objectsWHERE type IN ('FN', 'IF', 'TF') -- Scalar, Inline TVF, Multi-statement TVFORDER BY SchemaName, FunctionName; -- Check if function can be used in computed columnSELECT OBJECTPROPERTY(OBJECT_ID('dbo.MyFunction'), 'IsDeterministic') AS IsDeterministic, OBJECTPROPERTY(OBJECT_ID('dbo.MyFunction'), 'IsPrecise') AS IsPrecise;-- Both must be 1 for persisted computed columns -- Why is my function non-deterministic? Check dependenciesSELECT OBJECT_NAME(referencing_id) AS ReferencingFunction, referenced_entity_name AS ReferencedObject, CASE WHEN OBJECTPROPERTY(OBJECT_ID(referenced_entity_name), 'IsDeterministic') = 0 THEN 'Non-Deterministic Dependency' ELSE 'OK' END AS StatusFROM sys.sql_expression_dependenciesWHERE referencing_id = OBJECT_ID('dbo.MyFunction');Creating deterministic functions requires disciplined design that avoids all sources of non-determinism. The key principle is parameterize everything that varies—don't embed anything into the function that could change between calls.
123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081
-- Pattern 1: Replace time functions with parameters -- NON-DETERMINISTIC: Uses GETDATE() internallyCREATE FUNCTION dbo.GetAge_Bad(@BirthDate DATE)RETURNS INTASBEGIN RETURN DATEDIFF(YEAR, @BirthDate, GETDATE()) - CASE WHEN DATEADD(YEAR, DATEDIFF(YEAR, @BirthDate, GETDATE()), @BirthDate) > GETDATE() THEN 1 ELSE 0 END;END; -- DETERMINISTIC: Receives reference date as parameterCREATE FUNCTION dbo.GetAge_Good(@BirthDate DATE, @AsOfDate DATE)RETURNS INTWITH SCHEMABINDINGASBEGIN RETURN DATEDIFF(YEAR, @BirthDate, @AsOfDate) - CASE WHEN DATEADD(YEAR, DATEDIFF(YEAR, @BirthDate, @AsOfDate), @BirthDate) > @AsOfDate THEN 1 ELSE 0 END;END; -- Pattern 2: Avoid reading from tables -- NON-DETERMINISTIC: Reads from configuration tableCREATE FUNCTION dbo.GetTaxRate_Bad(@StateCode CHAR(2))RETURNS DECIMAL(6,4)ASBEGIN DECLARE @Rate DECIMAL(6,4); SELECT @Rate = TaxRate FROM StateTaxRates WHERE StateCode = @StateCode; RETURN @Rate;END; -- DETERMINISTIC: Encode rates in function or receive as parameterCREATE FUNCTION dbo.GetTaxRate_Good(@StateCode CHAR(2))RETURNS DECIMAL(6,4)WITH SCHEMABINDINGASBEGIN RETURN CASE @StateCode WHEN 'CA' THEN 0.0725 WHEN 'NY' THEN 0.0800 WHEN 'TX' THEN 0.0625 WHEN 'WA' THEN 0.0650 ELSE 0.0500 END;END; -- Or for dynamic rates: pass rate as parameterCREATE FUNCTION dbo.CalculateTax(@Amount DECIMAL(18,2), @Rate DECIMAL(6,4))RETURNS DECIMAL(18,2)WITH SCHEMABINDINGASBEGIN RETURN ROUND(@Amount * @Rate, 2);END; -- Pattern 3: Pure mathematical/logical computationCREATE FUNCTION dbo.Fibonacci(@N INT)RETURNS BIGINTWITH SCHEMABINDINGASBEGIN IF @N < 0 RETURN NULL; IF @N <= 1 RETURN @N; DECLARE @a BIGINT = 0, @b BIGINT = 1, @c BIGINT; DECLARE @i INT = 2; WHILE @i <= @N BEGIN SET @c = @a + @b; SET @a = @b; SET @b = @c; SET @i = @i + 1; END; RETURN @b;END;GETDATE(), CURRENT_TIMESTAMP, SYSDATETIME() with parametersRAND(), NEWID(), NEWSEQUENTIALID()@@SPID, USER_NAME(), SESSION_USERHOST_NAME(), APP_NAME(), @@SERVERNAMEIn SQL Server, SCHEMABINDING is intimately connected with determinism because it prevents changes to underlying objects that could affect function behavior. A function without SCHEMABINDING cannot be reliably verified as deterministic because its dependencies might change.
When you create a function WITH SCHEMABINDING:
1234567891011121314151617181920212223242526272829303132333435363738394041424344454647484950515253545556575859606162636465
-- Understanding SCHEMABINDING requirements and effects -- Schema-bound function: must use two-part names (schema.object)CREATE FUNCTION dbo.FormatCurrency(@Amount DECIMAL(18,2))RETURNS VARCHAR(50)WITH SCHEMABINDING -- Enables determinism verificationASBEGIN -- Cannot reference dbo.SomeTable here - would make it non-deterministic -- Cannot use SELECT from any table IF @Amount IS NULL RETURN NULL; RETURN '$' + FORMAT(@Amount, 'N2');END;GO -- This IS deterministicSELECT OBJECTPROPERTY(OBJECT_ID('dbo.FormatCurrency'), 'IsDeterministic');-- Returns 1 -- What SCHEMABINDING prevents:-- 1. Cannot DROP referenced objects-- DROP TABLE dbo.SomeReferencedTable; -- Error if function references it -- 2. Cannot ALTER columns referenced by the function-- ALTER TABLE dbo.Table ALTER COLUMN ReferencedColumn INT; -- Error -- 3. Forces explicit schema qualification-- CREATE FUNCTION dbo.BadFunction(@X INT) RETURNS INT WITH SCHEMABINDING AS BEGIN RETURN X * 2; END;-- Error: Must use two-part name for 'X' (thinks X is a column reference) -- Example: Schema-bound function referencing another functionCREATE FUNCTION dbo.DoubleValue(@X INT)RETURNS INTWITH SCHEMABINDINGASBEGIN RETURN @X * 2;END;GO CREATE FUNCTION dbo.QuadrupleValue(@X INT)RETURNS INTWITH SCHEMABINDINGASBEGIN -- References another schema-bound function RETURN dbo.DoubleValue(dbo.DoubleValue(@X));END;GO -- Now you cannot drop DoubleValue:-- DROP FUNCTION dbo.DoubleValue; -- Error: Cannot drop function because it is being referenced by 'QuadrupleValue' -- Check schema dependenciesSELECT referencing_id, OBJECT_NAME(referencing_id) AS referencing_name, referenced_id, OBJECT_NAME(referenced_id) AS referenced_name, is_schema_bound_referenceFROM sys.sql_expression_dependenciesWHERE referenced_id = OBJECT_ID('dbo.DoubleValue');SCHEMABINDING adds deployment complexity: you must drop/recreate functions in reverse dependency order when making changes. However, this rigidity ensures determinism verification and protects against accidental breaks. For production systems with indexed views or persisted computed columns, SCHEMABINDING's guarantees are worth the deployment overhead.
PostgreSQL takes a more nuanced approach with three volatility categories: IMMUTABLE, STABLE, and VOLATILE. These categories provide finer-grained control over optimization and capability eligibility than SQL Server's binary deterministic/non-deterministic classification.
| Category | Guarantee | Optimizer Benefits | Use Cases |
|---|---|---|---|
| IMMUTABLE | Same result forever for same inputs | Can evaluate at plan time, use in indexes, maximum caching | Pure math, string manipulation, encoding/decoding |
| STABLE | Same result within single query/transaction | Can cache results within a query, used in index scans | Functions reading config, current_user, transaction-constant data |
| VOLATILE | Result may change at any time | Re-evaluated on every row, no caching | RANDOM(), NOW(), functions with side effects |
123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263
-- IMMUTABLE: Truly deterministic, can be used in indexes CREATE OR REPLACE FUNCTION slugify(text_input TEXT)RETURNS TEXTLANGUAGE SQLIMMUTABLE -- Same input = same output, foreverPARALLEL SAFEAS $$ SELECT LOWER( REGEXP_REPLACE( REGEXP_REPLACE(text_input, '[^a-zA-Z0-9]+', '-', 'g'), '^-+|-+$', '', 'g' ) );$$; -- Can create expression-based index!CREATE INDEX idx_products_slug ON products (slugify(product_name)); -- STABLE: Same result within a transaction CREATE OR REPLACE FUNCTION get_config_value(key TEXT)RETURNS TEXTLANGUAGE SQLSTABLE -- Reads config, which doesn't change mid-transactionAS $$ SELECT value FROM app_config WHERE config_key = key;$$; -- Cannot use in index (data might change)-- But optimizer can cache result within a query:SELECT * FROM orders WHERE store_id = get_config_value('default_store')::INT;-- Function called once, not for every row -- VOLATILE: May change at any time CREATE OR REPLACE FUNCTION generate_code()RETURNS TEXTLANGUAGE SQLVOLATILE -- Uses random, definitely not deterministicAS $$ SELECT 'CODE-' || LPAD(FLOOR(RANDOM() * 1000000)::TEXT, 6, '0');$$; -- Common mistake: Declaring RANDOM() function as STABLE-- DON'T DO THIS - results in incorrect optimization!CREATE OR REPLACE FUNCTION bad_random_function()RETURNS DOUBLE PRECISIONLANGUAGE SQLSTABLE -- WRONG! RANDOM() is VOLATILEAS $$ SELECT RANDOM();$$; -- The optimizer might evaluate this ONCE and reuse:SELECT *, bad_random_function() FROM generate_series(1, 10);-- All rows might get the SAME random value! -- Built-in function volatility examples:-- IMMUTABLE: abs(), length(), upper(), lower()-- STABLE: current_user, current_database(), current_setting()-- VOLATILE: random(), nextval(), timeofday(), clock_timestamp()PostgreSQL TRUSTS your volatility declaration. If you declare a VOLATILE function as IMMUTABLE, the optimizer may cache incorrect results, inline the function, or use it in constant folding—producing wrong query results. Always verify your volatility declaration matches actual function behavior.
When the query optimizer knows a function is deterministic, it can apply several powerful optimizations that dramatically improve query performance. Understanding these optimizations helps you appreciate why designing for determinism matters.
WHERE column = CalculateTax(100.00, 0.08) becomes WHERE column = 8.00.12345678910111213141516171819202122232425262728293031323334353637383940414243444546
-- Constant Folding demonstration -- Deterministic functionCREATE FUNCTION dbo.CircleArea(@Radius FLOAT)RETURNS FLOATWITH SCHEMABINDINGASBEGIN RETURN PI() * @Radius * @Radius;END; -- This query:SELECT ProductId, PriceFROM ProductsWHERE Price > dbo.CircleArea(10); -- Optimizer MAY simplify to:SELECT ProductId, PriceFROM ProductsWHERE Price > 314.159265358979; -- Computed at compile time -- Common Subexpression Elimination -- Query with repeated function call:SELECT ProductId, Price, dbo.CalculateTax(Price, 0.08) AS Tax, Price + dbo.CalculateTax(Price, 0.08) AS TotalWithTaxFROM ProductsWHERE dbo.CalculateTax(Price, 0.08) > 10; -- For each row, the function could be called 3 times-- With deterministic + optimization: called ONCE per row -- Parallel execution visibility-- Check if function blocks parallelismSELECT p.query_plan, p.query_plan.query('//RelOp[@PhysicalOp="Parallelism"]') AS ParallelOpsFROM sys.dm_exec_query_stats qsCROSS APPLY sys.dm_exec_query_plan(qs.plan_handle) pWHERE qs.sql_handle = /* your query's handle */; -- Non-deterministic functions often show:-- "NonParallelPlanReason = UDFInsideFilter"Let's examine practical scenarios where determinism design decisions have significant impact on system capabilities and performance.
123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112
-- =====================================================-- SCENARIO 1: Search Indexing-- Need to index normalized/standardized text for fast lookup-- ===================================================== -- Deterministic text normalizerCREATE FUNCTION dbo.NormalizeForSearch(@Text NVARCHAR(1000))RETURNS NVARCHAR(1000)WITH SCHEMABINDINGASBEGIN IF @Text IS NULL RETURN NULL; DECLARE @Result NVARCHAR(1000) = @Text; -- Remove accents (simplified) SET @Result = REPLACE(@Result, 'á', 'a'); SET @Result = REPLACE(@Result, 'é', 'e'); SET @Result = REPLACE(@Result, 'í', 'i'); SET @Result = REPLACE(@Result, 'ñ', 'n'); -- Lowercase SET @Result = LOWER(@Result); -- Remove extra whitespace WHILE CHARINDEX(' ', @Result) > 0 SET @Result = REPLACE(@Result, ' ', ' '); RETURN LTRIM(RTRIM(@Result));END;GO -- Create persisted computed columnALTER TABLE CustomersADD NameSearchable AS dbo.NormalizeForSearch(CustomerName) PERSISTED; -- Create index for fast normalized searchCREATE INDEX IX_Customer_NameSearchable ON Customers(NameSearchable); -- Fast searches now possibleSELECT * FROM Customers WHERE NameSearchable = dbo.NormalizeForSearch('José García'); -- =====================================================-- SCENARIO 2: Computed Business Keys-- Generate canonical identifiers for matching/deduplication-- ===================================================== CREATE FUNCTION dbo.GenerateCustomerMatchKey( @FirstName NVARCHAR(100), @LastName NVARCHAR(100), @DateOfBirth DATE, @SSNLast4 CHAR(4))RETURNS CHAR(32) -- MD5-length hex stringWITH SCHEMABINDINGASBEGIN -- Normalize and concatenate DECLARE @Normalized NVARCHAR(500); SET @Normalized = UPPER(LTRIM(RTRIM(@FirstName))) + '|' + UPPER(LTRIM(RTRIM(@LastName))) + '|' + CONVERT(CHAR(10), @DateOfBirth, 120) + '|' + @SSNLast4; -- Return hash RETURN CONVERT(CHAR(32), HASHBYTES('MD5', @Normalized), 2);END;GO -- Add to table as persisted columnALTER TABLE CustomersADD MatchKey AS dbo.GenerateCustomerMatchKey(FirstName, LastName, DateOfBirth, SSNLast4) PERSISTED; -- Index for duplicate detectionCREATE INDEX IX_Customer_MatchKey ON Customers(MatchKey); -- Find potential duplicates efficientlySELECT a.CustomerId, b.CustomerId, a.MatchKeyFROM Customers aJOIN Customers b ON a.MatchKey = b.MatchKey AND a.CustomerId < b.CustomerId; -- =====================================================-- SCENARIO 3: Tiered Pricing with Deterministic Lookups-- Complex pricing that needs to be indexed-- ===================================================== CREATE FUNCTION dbo.GetPriceTier(@UnitPrice DECIMAL(18,2))RETURNS CHAR(1)WITH SCHEMABINDINGASBEGIN RETURN CASE WHEN @UnitPrice < 10 THEN 'A' WHEN @UnitPrice < 50 THEN 'B' WHEN @UnitPrice < 100 THEN 'C' WHEN @UnitPrice < 500 THEN 'D' ELSE 'E' END;END;GO -- Indexed computed columnALTER TABLE ProductsADD PriceTier AS dbo.GetPriceTier(UnitPrice) PERSISTED; CREATE INDEX IX_Products_PriceTier ON Products(PriceTier)INCLUDE (ProductId, ProductName, UnitPrice); -- Fast tier-based queriesSELECT * FROM Products WHERE PriceTier = 'C';Function determinism is a fundamental property that determines what capabilities are available and how the optimizer can process your functions. Designing for determinism unlocks powerful features and optimizations.
You now understand function determinism comprehensively—from theoretical foundations to practical implementation across database platforms. The final page compares functions with stored procedures, helping you choose the right tool for each database programming task.