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

Query builder improvements #15725

Merged
merged 5 commits into from
Jun 30, 2020
Merged

Query builder improvements #15725

merged 5 commits into from
Jun 30, 2020

Conversation

gonzaloriestra
Copy link
Contributor

@gonzaloriestra gonzaloriestra commented Jun 30, 2020

Related to ch79934

Performance improvements for query builder (mostly for /viz) when having a big number of visualizations.

Basically 2 things:

  1. Fetch the related tables only after applying filters and limit, by using a subquery (only available when ordering by SQL)
  2. Do not fetch related tables for the count operations

For example, /dashboard/datasets generated a SQL like this (simplified):

SELECT * FROM "visualizations" 
LEFT OUTER JOIN "maps" ON "maps"."id" = "visualizations"."map_id" 
LEFT OUTER JOIN "user_tables" ON "user_tables"."map_id" = "maps"."id" 
LEFT OUTER JOIN "layers_user_tables" ON "layers_user_tables"."user_table_id" = "user_tables"."id" 
LEFT OUTER JOIN "layers" ON "layers"."id" = "layers_user_tables"."layer_id" 
LEFT OUTER JOIN "layers_maps" ON "layers_maps"."layer_id" = "layers"."id" 
LEFT OUTER JOIN "maps" "maps_layers" ON "maps_layers"."id" = "layers_maps"."map_id" 
LEFT OUTER JOIN "visualizations" "visualizations_maps" ON "visualizations_maps"."map_id" = "maps_layers"."id" 
LEFT OUTER JOIN "maps" "maps_visualizations" ON "maps_visualizations"."id" = "visualizations_maps"."map_id" 
LEFT OUTER JOIN "layers_maps" "layers_maps_maps_join" ON "layers_maps_maps_join"."map_id" = "maps_visualizations"."id" 
LEFT OUTER JOIN "layers" "layers_maps_2" ON "layers_maps_2"."id" = "layers_maps_maps_join"."layer_id" 
LEFT OUTER JOIN "layers_user_tables" "layers_user_tables_layers" ON "layers_user_tables_layers"."layer_id" = "layers_maps_2"."id" 
LEFT OUTER JOIN "permissions" ON "permissions"."id" = "visualizations_maps"."permission_id" 
LEFT OUTER JOIN "users" ON "users"."id" = "permissions"."owner_id" 
LEFT OUTER JOIN "permissions" "permissions_visualizations" ON "permissions_visualizations"."id" = "visualizations"."permission_id" 
LEFT OUTER JOIN "users" "owners_permissions" ON "owners_permissions"."id" = "permissions_visualizations"."owner_id" 
LEFT OUTER JOIN "synchronizations" ON "synchronizations"."visualization_id" = "visualizations"."id" 
LEFT OUTER JOIN "external_sources" ON "external_sources"."visualization_id" = "visualizations"."id" 
LEFT OUTER JOIN "users" "users_visualizations" ON "users_visualizations"."id" = "visualizations"."user_id" 
LEFT JOIN likes ON "likes"."subject" = "visualizations"."id" AND "likes"."actor" = 'd19b9f5a-0e72-4f95-8ca2-a97ae222df6a' 
WHERE "visualizations"."user_id" = 'd19b9f5a-0e72-4f95-8ca2-a97ae222df6a' 
AND "visualizations"."locked" = 'f' 
AND "visualizations"."type" = 'table'  
ORDER BY (likes.actor IS NOT NULL) desc,visualizations.updated_at desc 
LIMIT 12 OFFSET 0;

And now, it will generate something like:

SELECT * FROM (
  SELECT "visualizations".* FROM "visualizations" 
  LEFT JOIN likes ON "likes"."subject" = "visualizations"."id" AND "likes"."actor" = 'd19b9f5a-0e72-4f95-8ca2-a97ae222df6a'
  WHERE "visualizations"."user_id" = 'd19b9f5a-0e72-4f95-8ca2-a97ae222df6a'
  AND "visualizations"."locked" = 'f'
  AND "visualizations"."type" = 'table'
  ORDER BY (likes.actor IS NOT NULL) desc,visualizations.updated_at desc
  LIMIT 12 OFFSET 0
) visualizations 
LEFT OUTER JOIN "maps" ON "maps"."id" = "visualizations"."map_id" 
LEFT OUTER JOIN "user_tables" ON "user_tables"."map_id" = "maps"."id" 
LEFT OUTER JOIN "layers_user_tables" ON "layers_user_tables"."user_table_id" = "user_tables"."id" 
LEFT OUTER JOIN "layers" ON "layers"."id" = "layers_user_tables"."layer_id" 
LEFT OUTER JOIN "layers_maps" ON "layers_maps"."layer_id" = "layers"."id" 
LEFT OUTER JOIN "maps" "maps_layers" ON "maps_layers"."id" = "layers_maps"."map_id" 
LEFT OUTER JOIN "visualizations" "visualizations_maps" ON "visualizations_maps"."map_id" = "maps_layers"."id" 
LEFT OUTER JOIN "maps" "maps_visualizations" ON "maps_visualizations"."id" = "visualizations_maps"."map_id" 
LEFT OUTER JOIN "layers_maps" "layers_maps_maps_join" ON "layers_maps_maps_join"."map_id" = "maps_visualizations"."id" 
LEFT OUTER JOIN "layers" "layers_maps_2" ON "layers_maps_2"."id" = "layers_maps_maps_join"."layer_id" 
LEFT OUTER JOIN "layers_user_tables" "layers_user_tables_layers" ON "layers_user_tables_layers"."layer_id" = "layers_maps_2"."id" 
LEFT OUTER JOIN "permissions" ON "permissions"."id" = "visualizations_maps"."permission_id" 
LEFT OUTER JOIN "users" ON "users"."id" = "permissions"."owner_id" 
LEFT OUTER JOIN "permissions" "permissions_visualizations" ON "permissions_visualizations"."id" = "visualizations"."permission_id" 
LEFT OUTER JOIN "users" "owners_permissions" ON "owners_permissions"."id" = "permissions_visualizations"."owner_id" 
LEFT OUTER JOIN "synchronizations" ON "synchronizations"."visualization_id" = "visualizations"."id" 
LEFT OUTER JOIN "external_sources" ON "external_sources"."visualization_id" = "visualizations"."id" 
LEFT OUTER JOIN "users" "users_visualizations" ON "users_visualizations"."id" = "visualizations"."user_id";

This query takes around 400ms for a case with 20k tables with related stuff, while the old one takes around 40 seconds.

Already tested in staging.

@gonzaloriestra gonzaloriestra marked this pull request as ready for review June 30, 2020 07:58
Copy link
Contributor

@amiedes amiedes left a comment

Choose a reason for hiding this comment

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

👍

@gonzaloriestra gonzaloriestra merged commit 017d619 into master Jun 30, 2020
@gonzaloriestra gonzaloriestra deleted the query-builder-improvements branch June 30, 2020 11:18
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

None yet

2 participants