How to Fix: JSON_VALUE Returns NULL with Long Strings (SQL Server)

If you’re using JSON_VALUE() to return values consisting of a long string, you might find that it returns NULL instead of the actual value.

Or, you might be getting an error.

The Cause

This issue occurs because JSON_VALUE() returns a single text value of type nvarchar(4000).

When using JSON_VALUE() to return strings longer than 4000 characters, you’ll get either an error or a NULL value, depending on the path mode you’re using.

Lax Mode vs Strict Mode

Whether you get an error or NULL will depend on whether you use lax or strict mode.

When the value is greater than 4000 characters:

  • In lax mode, JSON_VALUE() returns null.
  • In strict mode, JSON_VALUE() returns an error.

Example of the Problem

Here’s an example of code that causes the problem.

Let’s do two example; one in lax mode, and the other in strict mode.

Lax Mode

DECLARE @json nvarchar(max) = N'{ 
    "article" : {
            "id" : 1,
            "text" : "If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error."
    }
}';
SELECT JSON_VALUE(@json, 'lax $.article.text');

Result:

+--------------------+
| (No column name)   |
|--------------------|
| NULL               |
+--------------------+

As mentioned, in lax mode it returns NULL.

Strict Mode

DECLARE @json nvarchar(max) = N'{ 
    "article" : {
            "id" : 1,
            "text" : "If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error."
    }
}';
SELECT JSON_VALUE(@json, 'strict $.article.text');

Result:

Msg 13625, Level 16, State 1, Line 7
String value in the specified JSON path would be truncated.

As expected, we get an error. Fortunately the error provides a clue as to what went wrong, as it mentions that the string value would be truncated.

Solution

Fortunately, the OPENJSON() function doesn’t have the same 4000 character limitation that JSON_VALUE() has on its return value.

OPENJSON() returns JSON values as an nvarchar(max).

Therefore, we can use the following code to resolve the issue.

DECLARE @json nvarchar(max) = N'{ 
    "article" : {
            "id" : 1,
            "text" : "If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error."
    }
}';
SELECT text FROM OPENJSON(@json, '$.article') 
WITH (text nvarchar(max) '$.text');

Result:

If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error. If you have to return scalar values greater than 4000 characters, use the OPENJSON function instead of JSON_VALUE. This text contains more than 4000 characters, which will cause issues for the JSON_VALUE function in SQL Server. This is because the JSON_VALUE function returns a single text value of type nvarchar(4000). If the value is greater than 4000 characters: In lax mode, JSON_VALUE returns null. In strict mode, JSON_VALUE returns an error.