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

SQL queries performance enhancement #9266

Merged
merged 7 commits into from
Oct 27, 2023

Conversation

dashevchenko
Copy link
Contributor

@dashevchenko dashevchenko commented Sep 15, 2023

Pull Request description

Added null-check for search text in sql queries and replaced 'LIKE' operator with case insensetive function 'ilike'.

General checklist

  • You have reviewed the guidelines document.
  • Labels that classify your pull request have been added.
  • The milestone is specified and corresponds to fix version.
  • Description references specific issue.
  • Description contains human-readable scope of changes.
  • Description contains brief notes about what needs to be added to the documentation.
  • No merge conflicts, commented blocks of code, code formatting issues.
  • Changes are backward compatible or upgrade script is provided.
  • Similar PR is opened for PE version to simplify merge. Crosslinks between PRs added. Required for internal contributors only.

Front-End feature checklist

  • Screenshots with affected component(s) are added. The best option is to provide 2 screens: before and after changes;
  • If you change the widget or other API, ensure it is backward-compatible or upgrade script is present.
  • Ensure new API is documented here

Back-End feature checklist

  • Added corresponding unit and/or integration test(s). Provide written explanation in the PR description if you have failed to add tests.
  • If new dependency was added: the dependency tree is checked for conflicts.
  • If new service was added: the service is marked with corresponding @TbCoreComponent, @TbRuleEngineComponent, @TbTransportComponent, etc.
  • If new REST API was added: the RestClient.java was updated, issue for Python REST client is created.

…perator with case insensetive function 'ilike'
@dashevchenko dashevchenko changed the title SQL queries performance enhancement [3.6.1] SQL queries performance enhancement Sep 15, 2023
public class ThingsboardPostgreSQLDialect extends org.hibernate.dialect.PostgreSQL10Dialect {
public ThingsboardPostgreSQLDialect() {
super();
registerFunction("ilike", new SQLFunctionTemplate(BooleanType.INSTANCE, "(?1 ILIKE ?2)"));
Copy link
Contributor

Choose a reason for hiding this comment

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

Should ilike always be in lowercase or can we use ILIKE too?

Copy link
Contributor Author

Choose a reason for hiding this comment

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

we can use ILIKE too

Copy link
Member

Choose a reason for hiding this comment

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

Please provide an example of the SQL statement that is generated based on @query and this dialect. I would like to double check that the final SQL statement uses ILIKE without any overhead

Copy link
Contributor

@smatvienko-tb smatvienko-tb Oct 12, 2023

Choose a reason for hiding this comment

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

SQL test property

spring.jpa.show-sql=true
spring.jpa.properties.hibernate.format_sql=true

I believe
It is an excessive parenthesis.

Hibernate: 
    select
        deviceenti0_.id as id1_18_,
        deviceenti0_.created_time as created_2_18_,
        deviceenti0_.additional_info as addition3_18_,
        deviceenti0_.customer_id as customer4_18_,
        deviceenti0_.device_data as device_d5_18_,
        deviceenti0_.device_profile_id as device_p6_18_,
        deviceenti0_.external_id as external7_18_,
        deviceenti0_.firmware_id as firmware8_18_,
        deviceenti0_.label as label9_18_,
        deviceenti0_.name as name10_18_,
        deviceenti0_.software_id as softwar11_18_,
        deviceenti0_.tenant_id as tenant_12_18_,
        deviceenti0_.type as type13_18_ 
    from
        device deviceenti0_ 
    where
        deviceenti0_.tenant_id=? 
        and (
            (
                deviceenti0_.name ILIKE ('%'||?||'%')
            )=true 
            or (
                deviceenti0_.label ILIKE ('%'||?||'%')
            )=true
        ) 
    order by
        deviceenti0_.id asc nulls last limit ?

Copy link
Contributor

@smatvienko-tb smatvienko-tb Oct 12, 2023

Choose a reason for hiding this comment

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

without parenthesis

registerFunction("ilike", new SQLFunctionTemplate(StandardBasicTypes.BOOLEAN, "?1 ILIKE ?2"));
    from
        device deviceenti0_ 
    where
        deviceenti0_.tenant_id=? 
        and (
            deviceenti0_.name ILIKE ('%'||?||'%')=true 
            or deviceenti0_.label ILIKE ('%'||?||'%')=true
        ) 
    order by
        deviceenti0_.id asc nulls last limit ?

@dashevchenko dashevchenko changed the base branch from develop/3.6 to master September 27, 2023 12:07
@dashevchenko dashevchenko changed the title [3.6.1] SQL queries performance enhancement SQL queries performance enhancement Oct 11, 2023
Copy link
Contributor

@smatvienko-tb smatvienko-tb left a comment

Choose a reason for hiding this comment

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

I waiting so long for such an improvement. Good job!
In general, the PR will bring some performance for big datasets.
But it still will use full scan, and full-text indexes will not help to search by many columns (OR clause).

The HQL dialect looks valid. I don't like to use a custom hql function, but I can not provide you with a better implementation

@@ -139,3 +139,5 @@ queue.rule-engine.queues[2].partitions=2
queue.rule-engine.queues[2].processing-strategy.retries=1
queue.rule-engine.queues[2].processing-strategy.pause-between-retries=0
queue.rule-engine.queues[2].processing-strategy.max-pause-between-retries=0

spring.jpa.properties.hibernate.dialect=org.thingsboard.server.dao.ThingsboardPostgreSQLDialect
Copy link
Contributor

Choose a reason for hiding this comment

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

Please, place the dislect along with spring.datasource.url (sql, no-sql)
application-test does not responsible for db connection
image

public class ThingsboardPostgreSQLDialect extends org.hibernate.dialect.PostgreSQL10Dialect {
public ThingsboardPostgreSQLDialect() {
super();
registerFunction("ilike", new SQLFunctionTemplate(BooleanType.INSTANCE, "(?1 ILIKE ?2)"));
Copy link
Contributor

@smatvienko-tb smatvienko-tb Oct 12, 2023

Choose a reason for hiding this comment

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

SQL test property

spring.jpa.show-sql=true
spring.jpa.properties.hibernate.format_sql=true

I believe
It is an excessive parenthesis.

Hibernate: 
    select
        deviceenti0_.id as id1_18_,
        deviceenti0_.created_time as created_2_18_,
        deviceenti0_.additional_info as addition3_18_,
        deviceenti0_.customer_id as customer4_18_,
        deviceenti0_.device_data as device_d5_18_,
        deviceenti0_.device_profile_id as device_p6_18_,
        deviceenti0_.external_id as external7_18_,
        deviceenti0_.firmware_id as firmware8_18_,
        deviceenti0_.label as label9_18_,
        deviceenti0_.name as name10_18_,
        deviceenti0_.software_id as softwar11_18_,
        deviceenti0_.tenant_id as tenant_12_18_,
        deviceenti0_.type as type13_18_ 
    from
        device deviceenti0_ 
    where
        deviceenti0_.tenant_id=? 
        and (
            (
                deviceenti0_.name ILIKE ('%'||?||'%')
            )=true 
            or (
                deviceenti0_.label ILIKE ('%'||?||'%')
            )=true
        ) 
    order by
        deviceenti0_.id asc nulls last limit ?

public class ThingsboardPostgreSQLDialect extends org.hibernate.dialect.PostgreSQL10Dialect {
public ThingsboardPostgreSQLDialect() {
super();
registerFunction("ilike", new SQLFunctionTemplate(BooleanType.INSTANCE, "(?1 ILIKE ?2)"));
Copy link
Contributor

@smatvienko-tb smatvienko-tb Oct 12, 2023

Choose a reason for hiding this comment

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

without parenthesis

registerFunction("ilike", new SQLFunctionTemplate(StandardBasicTypes.BOOLEAN, "?1 ILIKE ?2"));
    from
        device deviceenti0_ 
    where
        deviceenti0_.tenant_id=? 
        and (
            deviceenti0_.name ILIKE ('%'||?||'%')=true 
            or deviceenti0_.label ILIKE ('%'||?||'%')=true
        ) 
    order by
        deviceenti0_.id asc nulls last limit ?

@ashvayka ashvayka merged commit e5ce760 into thingsboard:master Oct 27, 2023
2 of 3 checks passed
@ashvayka ashvayka modified the milestones: 3.6, 3.6.1 Nov 13, 2023
@ashvayka ashvayka added the Core Changes to Core label Nov 13, 2023
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
Core Changes to Core
Projects
None yet
Development

Successfully merging this pull request may close these issues.

None yet

4 participants