Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

SqlServer never returns null for nullable Boolean expressions #34001

Open
ranma42 opened this issue Jun 16, 2024 · 2 comments
Open

SqlServer never returns null for nullable Boolean expressions #34001

ranma42 opened this issue Jun 16, 2024 · 2 comments

Comments

@ranma42
Copy link
Contributor

ranma42 commented Jun 16, 2024

The SqlServer provider never returns null for bool? expressions; instead it returns false.

An example program that showcases the bug is:

using System;
using System.Data;
using System.Linq;
using Microsoft.EntityFrameworkCore;

using var db = new BloggingContext();

var qs = db.Blogs
	.Select(x => x.NullableInt > 0)
    .ToQueryString();

Console.WriteLine(qs);

public class BloggingContext : DbContext
{
    public DbSet<Blog> Blogs { get; set; }

    protected override void OnConfiguring(DbContextOptionsBuilder options)
        => options
            .LogTo(Console.WriteLine, Microsoft.Extensions.Logging.LogLevel.Information)
            .UseSqlServer();

    protected override void OnModelCreating(ModelBuilder modelBuilder)
    {
		modelBuilder.Entity<Blog>().HasData(new Blog { BlogId = 1, NullableInt = 0 });
		modelBuilder.Entity<Blog>().HasData(new Blog { BlogId = 2, NullableInt = 1 });
		modelBuilder.Entity<Blog>().HasData(new Blog { BlogId = 3, NullableInt = null });
    }
}

public class Blog
{
    public int BlogId { get; set; }
	public int? NullableInt { get; set; }
}

The query is translated to

SELECT CASE
    WHEN [b].[NullableInt] > 0 THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END
FROM [Blogs] AS [b]

hence the result of the SELECT can only be 0 or 1 (this also happens by actually performing the query; in that case it obviously requires a running instance of SqlServer).

Include provider and version information

EF Core version: 8.0.6
Database provider: Microsoft.EntityFrameworkCore.SqlServer
Target framework: .NET 8.0
Operating system: Linux (/WSL)
IDE: Visual Studio Code 1.89.1

@ranma42
Copy link
Contributor Author

ranma42 commented Jun 27, 2024

Some specific bool? expression already work (example: propagating the value of a nullable column).
The problem is related to the conversion from Boolean to BIT (it mixes false and NULL values)

@ranma42 ranma42 changed the title SqlServer never returns null for bool? expressions SqlServer never returns null for nullable Boolean expressions Jun 27, 2024
ranma42 added a commit to ranma42/efcore that referenced this issue Jun 27, 2024
When neither the parent expression nor the inner one is a predicate, translate to:
```sql
x ^ CAST(1 AS bit)
```

instead of

```sql
CASE
    WHEN x = CAST(0 AS bit) THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END
```

Contributes to dotnet#34001 for simple cases (NOT of BIT expressions).
ranma42 added a commit to ranma42/efcore that referenced this issue Jun 27, 2024
When neither the parent expression nor the inner one is a predicate, translate to:
```sql
x ^ CAST(1 AS bit)
```

instead of

```sql
CASE
    WHEN x = CAST(0 AS bit) THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END
```

Contributes to dotnet#34001 for simple cases (NOT of BIT expressions).
maumar pushed a commit that referenced this issue Jun 28, 2024
Use `XOR` to translate some `NOT` expressions

When neither the parent expression nor the inner one is a predicate, translate to:
```sql
x ^ CAST(1 AS bit)
```

instead of

```sql
CASE
    WHEN x = CAST(0 AS bit) THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END
```

Contributes to #34001 for simple cases (NOT of BIT expressions).
ranma42 added a commit to ranma42/efcore that referenced this issue Jun 30, 2024
When the parent expression is not a predicate, translate `x != y` to:
```sql
x ^ y
```

instead of

```sql
CASE
    WHEN x <> y THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END
```

Similarly, translate `x == y` to:

```sql
x ^ y ^ CAST(1 AS bit)
```

instead of

```sql
CASE
    WHEN x == y THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END
```

Contributes to dotnet#34001 for simple cases (comparison of BIT expressions).
ranma42 added a commit to ranma42/efcore that referenced this issue Jul 2, 2024
When the parent expression is not a predicate, translate `x != y` to:
```sql
x ^ y
```

instead of

```sql
CASE
    WHEN x <> y THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END
```

Similarly, translate `x == y` to:

```sql
x ^ y ^ CAST(1 AS bit)
```

instead of

```sql
CASE
    WHEN x == y THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END
```

Contributes to dotnet#34001 for simple cases (comparison of BIT expressions).
ranma42 added a commit to ranma42/efcore that referenced this issue Jul 2, 2024
When the parent expression is not a predicate, translate `x != y` to:
```sql
x ^ y
```

instead of

```sql
CASE
    WHEN x <> y THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END
```

Similarly, translate `x == y` to:

```sql
x ^ y ^ CAST(1 AS bit)
```

instead of

```sql
CASE
    WHEN x == y THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END
```

Contributes to dotnet#34001 for simple cases (comparison of BIT expressions).
maumar pushed a commit that referenced this issue Jul 3, 2024
* Use XOR to translate some `==` and `!=` expressions

When the parent expression is not a predicate, translate `x != y` to:
```sql
x ^ y
```

instead of

```sql
CASE
    WHEN x <> y THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END
```

Similarly, translate `x == y` to:

```sql
x ^ y ^ CAST(1 AS bit)
```

instead of

```sql
CASE
    WHEN x == y THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END
```

Contributes to #34001 for simple cases (comparison of BIT expressions).
@ranma42
Copy link
Contributor Author

ranma42 commented Jul 3, 2024

I am investigating the possible translations. Currently the best candidate for an expression x seems to be:

CASE
    WHEN x IS NULL THEN NULL
    WHEN x THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END

The main advantage of this translation is that (as long as appropriate simplifications are performed), x IS NULL can be much simpler than x; in the trivial case in which x is not nullable, the clause would even simplify away completely.

ranma42 added a commit to ranma42/efcore that referenced this issue Jul 5, 2024
When the parent expression is not a predicate, translate `x != y` to:
```sql
CAST(x ^ y AS BIT)
```

instead of

```sql
CASE
    WHEN x <> y THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END
```

Similarly, translate `x == y` to:

```sql
CAST(x ^ y AS BIT) ^ CAST(1 AS bit)
```

instead of

```sql
CASE
    WHEN x == y THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END
```

Contributes to dotnet#34001.
ranma42 added a commit to ranma42/efcore that referenced this issue Jul 5, 2024
When the parent expression is not a predicate, translate `x != y` to:
```sql
CAST(x ^ y AS BIT)
```

instead of

```sql
CASE
    WHEN x <> y THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END
```

Similarly, translate `x == y` to:

```sql
CAST(x ^ y AS BIT) ^ CAST(1 AS bit)
```

instead of

```sql
CASE
    WHEN x == y THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END
```

Contributes to dotnet#34001.
maumar pushed a commit that referenced this issue Jul 9, 2024
* Use XOR to translate some == and != expressions

When the parent expression is not a predicate, translate `x != y` to:
```sql
CAST(x ^ y AS BIT)
```

instead of

```sql
CASE
    WHEN x <> y THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END
```

Similarly, translate `x == y` to:

```sql
CAST(x ^ y AS BIT) ^ CAST(1 AS bit)
```

instead of

```sql
CASE
    WHEN x == y THEN CAST(1 AS bit)
    ELSE CAST(0 AS bit)
END
```

Contributes to #34001
@cincuranet cincuranet added this to the 9.0.0 milestone Jul 19, 2024
@maumar maumar modified the milestones: 9.0.0, Backlog Aug 8, 2024
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Projects
None yet
Development

No branches or pull requests

4 participants