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

Fix for slow query on MS SQL #22522

Merged
merged 9 commits into from
Jun 5, 2024
Merged

Fix for slow query on MS SQL #22522

merged 9 commits into from
Jun 5, 2024

Conversation

boring-joey
Copy link
Contributor

What's changed:

  • Resolved performance issue related to long-running queries in Azure SQL Database.
  • Simplified conditions in SQL queries to improve execution times.
  • Added optimization steps for better handling of schema updates in Directus.

Potential Risks / Drawbacks

  • Changes in SQL query handling might affect other parts of the system that rely on similar queries.

Review Notes / Questions

  • Please review the changes made to SQL query conditions and confirm they do not impact other functionalities.
  • Special attention should be paid to the handling of NULL values and the use of temporary tables for intermediate results.

Fixes #19486

You can review the related issue here.
#19486

Copy link

changeset-bot bot commented May 19, 2024

🦋 Changeset detected

Latest commit: d5c7b19

The changes in this PR will be included in the next version bump.

This PR includes changesets to release 8 packages
Name Type
@directus/schema Patch
@directus/api Patch
@directus/types Patch
directus Patch
@directus/extensions-sdk Patch
@directus/extensions Patch
create-directus-extension Patch
@directus/extensions-registry Patch

Not sure what this means? Click here to learn what changesets are.

Click here if you're a maintainer who wants to add another changeset to this PR

@jaads jaads self-requested a review May 21, 2024 15:04
@jaads jaads self-assigned this May 21, 2024
Copy link
Member

@nickrum nickrum left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

If I understand it correctly, this completely removes the check which ensures that is_primary_key and is_unique are only set if index_column_count and index_priority are either 1 or NULL. Can we really drop that?

My best guess for the slow query is that using a function and a comparison, that does not establish a relation between the joined tables, inside the ON expression of a join somehow hits a slow path in Azure. Maybe moving the check into the subquery would help.

@boring-joey
Copy link
Contributor Author

@nickrum, is this something the Directus team will investigate further, or would you like me to look into it more? I noticed the issue has been moved to 'ready,' so I'm curious about the status.

@jaads
Copy link
Member

jaads commented May 24, 2024

I'm currently looking into it. I cannot reproduce the issue but that's only because I don't have a big and complex enough schema in my ms sql database. we're currently thinking about how we can spin up an arbitrary schema to do performance tests for introspection but right now it's tricky / time consuming.

But I can confirm that the query in this PR does not return the same result as the current one. The one in this PR returns more records. I'll have to investigate now that this does not introduce any other problem.

However, the fact that the PR does not introduce any additional integration tests to fail is a good sign that we can use the updated query :)

@jaads
Copy link
Member

jaads commented May 27, 2024

I compared the query results further and noticed that the is_primary_key and is_unique are not correct. so unfortunately, we cannot use the updated query as it is right now

Copy link
Member

@jaads jaads left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

as described above

@alexchopin alexchopin modified the milestone: Next Minor Release May 30, 2024
@boring-joey
Copy link
Contributor Author

boring-joey commented Jun 3, 2024

I compared the query results further and noticed that the is_primary_key and is_unique are not correct. so unfortunately, we cannot use the updated query as it is right now

@jaads How did you verify this? Is there a test setup I can use to further evaluate the query's outcome? I'm happy to help resolve this issue. It remains a significant problem in our Azure environment, especially when editing our data model, as we are doing this month for our production website. Each data model edit currently takes 30-60 seconds, which is quite disruptive.

@jaads
Copy link
Member

jaads commented Jun 3, 2024

I enabled logging, started directus on the main branch, copied the introspection query from the logs into my sql editor, (deleted the schema condition at the very end of the query) and run the query. then I adopted the query with the changes from this PR, run it again and notice those mentioned differences.

however! now I did the same thing and but this time the output seem to be the same 🫨 so i'm either doing something wrong now or last time.

here are the queries for which I compared the results.
the current query:

select [o].[name]                                 AS [table],
       [c].[name]                                 AS [name],
       [t].[name]                                 AS [data_type],
       [c].[max_length]                           AS [max_length],
       [c].[precision]                            AS [numeric_precision],
       [c].[scale]                                AS [numeric_scale],
       CASE
           WHEN [c].[is_nullable] = 0 THEN
               'NO'
           ELSE
               'YES'
           END                                    AS [is_nullable],
       object_definition([c].[default_object_id]) AS [default_value],
       [i].[is_primary_key],
       [i].[is_unique],
       CASE [c].[is_identity]
           WHEN 1 THEN
               'YES'
           ELSE
               'NO'
           END                                    AS [has_auto_increment],
       OBJECT_NAME([fk].[referenced_object_id])   AS [foreign_key_table],
       COL_NAME([fk].[referenced_object_id],
                [fk].[referenced_column_id])      AS [foreign_key_column],
       [cc].[is_computed]                         as [is_generated],
       [cc].[definition]                          as [generation_expression]
from [master].[sys].[columns] [c]
         JOIN [sys].[types] [t] ON [c].[user_type_id] = [t].[user_type_id]
         JOIN [sys].[tables] [o] ON [o].[object_id] = [c].[object_id]
         JOIN [sys].[schemas] [s] ON [s].[schema_id] = [o].[schema_id]
         LEFT JOIN [sys].[computed_columns] AS [cc]
                   ON [cc].[object_id] = [c].[object_id] AND [cc].[column_id] = [c].[column_id]
         LEFT JOIN [sys].[foreign_key_columns] AS [fk]
                   ON [fk].[parent_object_id] = [c].[object_id] AND [fk].[parent_column_id] = [c].[column_id]
         LEFT JOIN (SELECT [ic].[object_id],
                           [ic].[column_id],
                           [ix].[is_unique],
                           [ix].[is_primary_key],
                           MAX([ic].[index_column_id])
                               OVER (partition by [ic].[index_id], [ic].[object_id])       AS index_column_count,
                           ROW_NUMBER() OVER (
                               PARTITION BY [ic].[object_id], [ic].[column_id]
                               ORDER BY [ix].[is_primary_key] DESC, [ix].[is_unique] DESC) AS index_priority
                    FROM [sys].[index_columns] [ic]
                             JOIN [sys].[indexes] AS [ix] ON [ix].[object_id] = [ic].[object_id]
                        AND [ix].[index_id] = [ic].[index_id]) AS [i] ON [i].[object_id] = [c].[object_id]
    AND [i].[column_id] = [c].[column_id]
    AND ISNULL([i].[index_column_count], 1) = 1
    AND ISNULL([i].[index_priority], 1) = 1;

and the updated query from this PR

select [o].[name]                                 AS [table],
       [c].[name]                                 AS [name],
       [t].[name]                                 AS [data_type],
       [c].[max_length]                           AS [max_length],
       [c].[precision]                            AS [numeric_precision],
       [c].[scale]                                AS [numeric_scale],
       CASE
           WHEN [c].[is_nullable] = 0 THEN
               'NO'
           ELSE
               'YES'
           END                                    AS [is_nullable],
       object_definition([c].[default_object_id]) AS [default_value],
       [i].[is_primary_key],
       [i].[is_unique],
       CASE [c].[is_identity]
           WHEN 1 THEN
               'YES'
           ELSE
               'NO'
           END                                    AS [has_auto_increment],
       OBJECT_NAME([fk].[referenced_object_id])   AS [foreign_key_table],
       COL_NAME([fk].[referenced_object_id],
                [fk].[referenced_column_id])      AS [foreign_key_column],
       [cc].[is_computed]                         as [is_generated],
       [cc].[definition]                          as [generation_expression]
from [master].[sys].[columns] [c]
         JOIN [sys].[types] [t] ON [c].[user_type_id] = [t].[user_type_id]
         JOIN [sys].[tables] [o] ON [o].[object_id] = [c].[object_id]
         JOIN [sys].[schemas] [s] ON [s].[schema_id] = [o].[schema_id]
         LEFT JOIN [sys].[computed_columns] AS [cc]
                   ON [cc].[object_id] = [c].[object_id] AND [cc].[column_id] = [c].[column_id]
         LEFT JOIN [sys].[foreign_key_columns] AS [fk]
                   ON [fk].[parent_object_id] = [c].[object_id] AND [fk].[parent_column_id] = [c].[column_id]
         LEFT JOIN (SELECT [ic].[object_id],
                           [ic].[column_id],
                           [ix].[is_unique],
                           [ix].[is_primary_key],
                           COALESCE(MAX([ic].[index_column_id])
                                        OVER (partition by [ic].[index_id], [ic].[object_id]), 1) AS index_column_count,
                           COALESCE(ROW_NUMBER() OVER (
                               PARTITION BY [ic].[object_id], [ic].[column_id]
                               ORDER BY [ix].[is_primary_key] DESC, [ix].[is_unique] DESC), 1)   AS index_priority
                    FROM [sys].[index_columns] [ic]
                             JOIN [sys].[indexes] AS [ix] ON [ix].[object_id] = [ic].[object_id]
                        AND [ix].[index_id] = [ic].[index_id]) AS [i] ON [i].[object_id] = [c].[object_id]
    AND [i].[column_id] = [c].[column_id];

are the results the same for you? @boring-joey 🤔

@boring-joey
Copy link
Contributor Author

boring-joey commented Jun 4, 2024

@jaads Then the results are not the same. Thing is that we see a different running query in our Azure Logs. If i compare that query with the optimized query the results are the same in my case.

I see this query in our Azure Logs as Long running Queries, mind the DATABASENAME part:

select 
        [o].[name] AS [table],
        [c].[name] AS [name],
        [t].[name] AS [data_type],
        [c].[max_length] AS [max_length],
        [c].[precision] AS [numeric_precision],
        [c].[scale] AS [numeric_scale],
        CASE WHEN [c].[is_nullable] = 0 THEN
          'NO'
        ELSE
          'YES'
        END AS [is_nullable],
        object_definition ([c].[default_object_id]) AS [default_value],
        [i].[is_primary_key],
        [i].[is_unique],
        CASE [c].[is_identity]
        WHEN 1 THEN
          'YES'
        ELSE
          'NO'
        END AS [has_auto_increment],
        OBJECT_NAME ([fk].[referenced_object_id]) AS [foreign_key_table],
        COL_NAME ([fk].[referenced_object_id],
          [fk].[referenced_column_id]) AS [foreign_key_column],
        [cc].[is_computed] as [is_generated],
        [cc].[definition] as [generation_expression] from [**DATABASENAME**].[sys].[columns] [c] JOIN [sys].[types] [t] ON [c].[user_type_id] = [t].[user_type_id] JOIN [sys].[tables] [o] ON [o].[object_id] = [c].[object_id] JOIN [sys].[schemas] [s] ON [s].[schema_id] = [o].[schema_id] LEFT JOIN [sys].[computed_columns] AS [cc] ON [cc].[object_id] = [c].[object_id] AND [cc].[column_id] = [c].[column_id] LEFT JOIN [sys].[foreign_key_columns] AS [fk] ON [fk].[parent_object_id] = [c].[object_id] AND [fk].[parent_column_id] = [c].[column_id] LEFT JOIN (
          SELECT
            [ic].[object_id],
            [ic].[column_id],
            [ix].[is_unique],
            [ix].[is_primary_key],
            MAX([ic].[index_column_id]) OVER(partition by [ic].[index_id], [ic].[object_id]) AS index_column_count,
            ROW_NUMBER() OVER (
              PARTITION BY [ic].[object_id], [ic].[column_id]
              ORDER BY [ix].[is_primary_key] DESC, [ix].[is_unique] DESC
            ) AS index_priority
          FROM
            [sys].[index_columns] [ic]
          JOIN [sys].[indexes] AS [ix] ON [ix].[object_id] = [ic].[object_id]
            AND [ix].[index_id] = [ic].[index_id]
        ) AS [i]
        ON [i].[object_id] = [c].[object_id]
        AND [i].[column_id] = [c].[column_id]
        AND ISNULL([i].[index_column_count], 1) = 1
        AND ISNULL([i].[index_priority], 1) = 1 where [s].[name] = 'dbo'

I refactored the last part of the original query with a new version. Problem seems to be in the these lines:

AND ISNULL([i].[index_column_count], 1) = 1
AND ISNULL([i].[index_priority], 1) = 1;

Maby we can handle those NULLS in the JOIN by doing:

            ISNULL(MAX([ic].[index_column_id]) OVER(partition by [ic].[index_id], [ic].[object_id]), 1) AS index_column_count,
            ISNULL(ROW_NUMBER() OVER (
              PARTITION BY [ic].[object_id], [ic].[column_id]
              ORDER BY [ix].[is_primary_key] DESC, [ix].[is_unique] DESC
            ), 1) AS index_priority

@boring-joey
Copy link
Contributor Author

boring-joey commented Jun 4, 2024

@jaads I'm not sure what's going on, but when I remove the WHERE clause at the end of your original query, it runs quickly. However, when I add it back, it becomes slow again.

where [s].[name] = 'dbo'

It seems that the system table doesn't have a index on the schema name. Maby we can first get the ID of the active schema and then use this in the original query. That way we can keep the original query the same and use the ID as a declaration in the query. Like this:

DECLARE @schema_id INT;
SELECT @schema_id = [schema_id]
FROM [sys].[schemas]
WHERE [name] = 'dbo';

SELECT 
    [o].[name] AS [table],
    [c].[name] AS [name],
    [t].[name] AS [data_type],
    [c].[max_length] AS [max_length],
    [c].[precision] AS [numeric_precision],
    [c].[scale] AS [numeric_scale],
    CASE WHEN [c].[is_nullable] = 0 THEN 'NO' ELSE 'YES' END AS [is_nullable],
    OBJECT_DEFINITION([c].[default_object_id]) AS [default_value],
    [i].[is_primary_key],
    [i].[is_unique],
    CASE [c].[is_identity] WHEN 1 THEN 'YES' ELSE 'NO' END AS [has_auto_increment],
    OBJECT_NAME([fk].[referenced_object_id]) AS [foreign_key_table],
    COL_NAME([fk].[referenced_object_id], [fk].[referenced_column_id]) AS [foreign_key_column],
    [cc].[is_computed] AS [is_generated],
    [cc].[definition] AS [generation_expression]
FROM 
    [main-temp].[sys].[columns] [c]
    JOIN [sys].[types] [t] ON [c].[user_type_id] = [t].[user_type_id]
    JOIN [sys].[tables] [o] ON [o].[object_id] = [c].[object_id]
    JOIN [sys].[schemas] [s] ON [s].[schema_id] = [o].[schema_id]
    LEFT JOIN [sys].[computed_columns] AS [cc] ON [cc].[object_id] = [c].[object_id] AND [cc].[column_id] = [c].[column_id]
    LEFT JOIN [sys].[foreign_key_columns] AS [fk] ON [fk].[parent_object_id] = [c].[object_id] AND [fk].[parent_column_id] = [c].[column_id]
    LEFT JOIN (
        SELECT
            [ic].[object_id],
            [ic].[column_id],
            [ix].[is_unique],
            [ix].[is_primary_key],
            MAX([ic].[index_column_id]) OVER (PARTITION BY [ic].[index_id], [ic].[object_id]) AS index_column_count,
            ROW_NUMBER() OVER (PARTITION BY [ic].[object_id], [ic].[column_id] ORDER BY [ix].[is_primary_key] DESC, [ix].[is_unique] DESC) AS index_priority
        FROM
            [sys].[index_columns] [ic]
        JOIN [sys].[indexes] AS [ix] ON [ix].[object_id] = [ic].[object_id] AND [ix].[index_id] = [ic].[index_id]
    ) AS [i] ON [i].[object_id] = [c].[object_id] AND [i].[column_id] = [c].[column_id] AND ISNULL([i].[index_column_count], 1) = 1 AND ISNULL([i].[index_priority], 1) = 1
WHERE 
    [s].[schema_id] = @schema_id;

@jaads
Copy link
Member

jaads commented Jun 4, 2024

you're right. The query get indeed muuuuch, much slower when the where clause is added. with this I can also reproduce the issue now.

recently I removed that condition directly from the sql statement to introspect over all schemas since I though that way I would see the performance issue even more. but now it turned out that this clause actually cased the problem.

The above script look very nice! I wonder if we can sent this script with the variable definition to the database with one single request 🤔

@jaads
Copy link
Member

jaads commented Jun 5, 2024

ok unfortunately knex does not seem to support what I had in mind with sending the whole script

@jaads
Copy link
Member

jaads commented Jun 5, 2024

I disabled the blackbox tests again. no additional test were failing ✅

@boring-joey
Copy link
Contributor Author

ok unfortunately knex does not seem to support what I had in mind with sending the whole script

Maby we can convert the whole knex function to a knex.raw function with DECLARE @schema_id in front of the query? So everything will be executed with only one query. Let me know if i can do something to help.

Copy link
Member

@jaads jaads left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

The updated solution looks good 👍 tested locally and it actually increases the performance drastically

@paescuj paescuj requested a review from nickrum June 5, 2024 14:56
@jaads jaads merged commit a640781 into directus:main Jun 5, 2024
4 checks passed
@github-actions github-actions bot added this to the Next Release milestone Jun 5, 2024
@paescuj
Copy link
Member

paescuj commented Jun 5, 2024

Thanks @boring-joey ❤️🚀

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Projects
Status: ✅ Done
Development

Successfully merging this pull request may close these issues.

Slow schema introspection query with Azure SQL
5 participants