Categories: Snowflake

Cool Stuff in Snowflake – Part 12: IS DISTINCT FROM

I’m doing a little series on some of the nice features/capabilities in Snowflake (the cloud data warehouse). In each part, I’ll highlight something that I think it’s interesting enough to share. It might be some SQL function that I’d really like to be in SQL Server, it might be something else.

Often you want to check the values of a column for NULL values. Because NULL is evil, that’s way. Or you want to do a join and because NULL = NULL does not make sense, you want to make sure those rows can match as well if you have a nullable column in your key. In SQL Server, this will leave you open to the villainy of NULL if the key2 column is nullable:

FROM tableA A
JOIN tableB B ON A.key1 = B.key1
                 A.key2 = B.key2

Typically you resolve this with ISNULL:

FROM tableA A
JOIN tableB B ON A.key1 = B.key1
                 ISNULL(A.key2,'') = ISNULL(B.key2,'')

If the values are NULL, they will be replaced with an empty string and you can actually compare those with each other. But what about integers? You can use -1, but what if this value is actually present in the data? And what about dates? Furthermore, this solution might not use existing indexes because there’s now a function around key2 which prevents indexes from being used. Check out Sargable predicates. In a WHERE clause, you can fix it like this:

WHERE   A.key1 = B.key1
    AND (
            (A.key2 IS NULL AND B.key2 IS NULL)
        OR  (A.key2 = B.key2)
        )

Which of course leads to a more lengthy expression. In Snowflake, they have this interesting conditional expression: IS [NOT] DISTINCT FROM. Our join becomes:

FROM tableA A
JOIN tableB B ON A.key1 IS NOT DISTINCT FROM B.key1
             AND A.key2 IS NOT DISTINCT FROM B.key2

This single expression both checks for the equality of its members, but also checks the nullability of both columns. Awesome. A good habit would be to use IS [NOT] DISTINCT FROM instead of every = or <> in every expression (join clauses, WHERE clauses etc.) and you’ll never get burned by those pesky NULLs again!

p.s.: want this in SQL Server? Vote here!


------------------------------------------------
Do you like this blog post? You can thank me by buying me a beer 🙂
Koen Verbeeck

Koen Verbeeck is a Microsoft Business Intelligence consultant at AE, helping clients to get insight in their data. Koen has a comprehensive knowledge of the SQL Server BI stack, with a particular love for Integration Services. He's also a speaker at various conferences.

Recent Posts

Free webinar – Tackling the Gaps and Islands Problem with T-SQL Window Functions

I'm hosting a free webinar at MSSQLTips.com at the 19th of December 2024, 6PM UTC.…

5 days ago

dataMinds Connect 2024 – Session Materials

The slides and scripts for my session "Tackling the Gaps & Islands Problem with T-SQL…

4 weeks ago

Connect to Power BI as a Guest User in another Tenant

Sometimes your Microsoft Entra ID account (formerly known as Azure Active Directory) is added as…

2 months ago

How to use a Script Activity in ADF as a Lookup

In Azure Data Factory (ADF, but also Synapse Pipelines and Fabric Pipelines), you have a…

4 months ago

Database Build Error – Incorrect syntax near DISTINCT

I wrote a piece of SQL that had some new T-SQL syntax in it: IS…

4 months ago

Speaking at dataMinds Connect 2024

I'm very excited to announce I've been selected as a speaker for dataMinds Connect 2024,…

5 months ago