Merge pull request #3349 from omnivore-app/perf/slow-query
improve performance on db slow queries
This commit is contained in:
@ -93,6 +93,7 @@ export enum SortOrder {
|
||||
export interface Sort {
|
||||
by: string
|
||||
order?: SortOrder
|
||||
nulls?: 'NULLS FIRST' | 'NULLS LAST'
|
||||
}
|
||||
|
||||
interface Select {
|
||||
@ -332,8 +333,10 @@ export const buildQuery = (
|
||||
|
||||
const order =
|
||||
sortOrder === 'asc' ? SortOrder.ASCENDING : SortOrder.DESCENDING
|
||||
const nulls =
|
||||
order === SortOrder.ASCENDING ? 'NULLS FIRST' : 'NULLS LAST'
|
||||
|
||||
orders.push({ by: `library_item.${column}`, order })
|
||||
orders.push({ by: `library_item.${column}`, order, nulls })
|
||||
return null
|
||||
}
|
||||
case 'has':
|
||||
@ -613,12 +616,13 @@ export const searchLibraryItems = async (
|
||||
orders.push({
|
||||
by: 'library_item.saved_at',
|
||||
order: SortOrder.DESCENDING,
|
||||
nulls: 'NULLS LAST',
|
||||
})
|
||||
}
|
||||
|
||||
// add order by
|
||||
orders.forEach((order) => {
|
||||
queryBuilder.addOrderBy(order.by, order.order, 'NULLS LAST')
|
||||
queryBuilder.addOrderBy(order.by, order.order, order.nulls)
|
||||
})
|
||||
|
||||
const libraryItems = await queryBuilder.skip(from).take(size).getMany()
|
||||
|
||||
@ -1722,6 +1722,7 @@ describe('Article API', () => {
|
||||
readableContent: '<p>test 1</p>',
|
||||
slug: 'test slug 1',
|
||||
originalUrl: `${url}/test1`,
|
||||
savedAt: new Date(1703880588),
|
||||
},
|
||||
{
|
||||
user,
|
||||
@ -1729,6 +1730,7 @@ describe('Article API', () => {
|
||||
readableContent: '<p>test 2</p>',
|
||||
slug: 'test slug 2',
|
||||
originalUrl: `${url}/test2`,
|
||||
savedAt: new Date(1704880589),
|
||||
},
|
||||
{
|
||||
user,
|
||||
@ -1736,6 +1738,7 @@ describe('Article API', () => {
|
||||
readableContent: '<p>test 3</p>',
|
||||
slug: 'test slug 3',
|
||||
originalUrl: `${url}/test3`,
|
||||
savedAt: new Date(1705880590),
|
||||
},
|
||||
],
|
||||
user.id
|
||||
@ -1777,6 +1780,7 @@ describe('Article API', () => {
|
||||
readableContent: '<p>test 1</p>',
|
||||
slug: 'test slug 1',
|
||||
originalUrl: `${url}/test1`,
|
||||
savedAt: new Date(1703880588),
|
||||
},
|
||||
{
|
||||
user,
|
||||
@ -1784,6 +1788,7 @@ describe('Article API', () => {
|
||||
readableContent: '<p>test 2</p>',
|
||||
slug: 'test slug 2',
|
||||
originalUrl: `${url}/test2`,
|
||||
savedAt: new Date(1704880589),
|
||||
},
|
||||
{
|
||||
user,
|
||||
@ -1791,6 +1796,7 @@ describe('Article API', () => {
|
||||
readableContent: '<p>test 3</p>',
|
||||
slug: 'test slug 3',
|
||||
originalUrl: `${url}/test3`,
|
||||
savedAt: new Date(1705880590),
|
||||
},
|
||||
],
|
||||
user.id
|
||||
|
||||
6
packages/db/migrations/0153.do.library_item_user_id_saved_at_idx.sql
Executable file
6
packages/db/migrations/0153.do.library_item_user_id_saved_at_idx.sql
Executable file
@ -0,0 +1,6 @@
|
||||
-- Type: DO
|
||||
-- Name: library_item_user_id_saved_at_idx
|
||||
-- Description: Add library_item_user_id_saved_at_idx index on library_item table for user_id and saved_at
|
||||
|
||||
-- create index for sorting concurrently to avoid locking
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS library_item_user_id_saved_at_idx ON omnivore.library_item (user_id, saved_at DESC NULLS LAST);
|
||||
9
packages/db/migrations/0153.undo.library_item_user_id_saved_at_idx.sql
Executable file
9
packages/db/migrations/0153.undo.library_item_user_id_saved_at_idx.sql
Executable file
@ -0,0 +1,9 @@
|
||||
-- Type: UNDO
|
||||
-- Name: library_item_user_id_saved_at_idx
|
||||
-- Description: Add library_item_user_id_saved_at_idx index on library_item table for user_id and saved_at
|
||||
|
||||
BEGIN;
|
||||
|
||||
DROP INDEX IF EXISTS omnivore.library_item_user_id_saved_at_idx;
|
||||
|
||||
COMMIT;
|
||||
6
packages/db/migrations/0154.do.library_item_user_id_updated_at_idx.sql
Executable file
6
packages/db/migrations/0154.do.library_item_user_id_updated_at_idx.sql
Executable file
@ -0,0 +1,6 @@
|
||||
-- Type: DO
|
||||
-- Name: library_item_user_id_updated_at_idx
|
||||
-- Description: Add library_item_user_id_saved_at_idx index on library_item table for user_id and updated_at
|
||||
|
||||
-- create index for sorting concurrently to avoid locking
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS library_item_user_id_updated_at_idx ON omnivore.library_item (user_id, updated_at DESC NULLS LAST);
|
||||
9
packages/db/migrations/0154.undo.library_item_user_id_updated_at_idx.sql
Executable file
9
packages/db/migrations/0154.undo.library_item_user_id_updated_at_idx.sql
Executable file
@ -0,0 +1,9 @@
|
||||
-- Type: UNDO
|
||||
-- Name: library_item_user_id_updated_at_idx
|
||||
-- Description: Add library_item_user_id_saved_at_idx index on library_item table for user_id and updated_at
|
||||
|
||||
BEGIN;
|
||||
|
||||
DROP INDEX IF EXISTS library_item_user_id_updated_at_idx;
|
||||
|
||||
COMMIT;
|
||||
6
packages/db/migrations/0155.do.library_item_user_id_published_at_idx.sql
Executable file
6
packages/db/migrations/0155.do.library_item_user_id_published_at_idx.sql
Executable file
@ -0,0 +1,6 @@
|
||||
-- Type: DO
|
||||
-- Name: library_item_user_id_published_at_idx
|
||||
-- Description: Add library_item_user_id_published_at_idx index on library_item table for user_id and published_at
|
||||
|
||||
-- create index for sorting concurrently to avoid locking
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS library_item_user_id_published_at_idx ON omnivore.library_item (user_id, published_at DESC NULLS LAST);
|
||||
@ -0,0 +1,9 @@
|
||||
-- Type: UNDO
|
||||
-- Name: library_item_user_id_published_at_idx
|
||||
-- Description: Add library_item_user_id_published_at_idx index on library_item table for user_id and published_at
|
||||
|
||||
BEGIN;
|
||||
|
||||
DROP INDEX IF EXISTS library_item_user_id_published_at_idx;
|
||||
|
||||
COMMIT;
|
||||
6
packages/db/migrations/0156.do.library_item_user_id_read_at_idx.sql
Executable file
6
packages/db/migrations/0156.do.library_item_user_id_read_at_idx.sql
Executable file
@ -0,0 +1,6 @@
|
||||
-- Type: DO
|
||||
-- Name: library_item_user_id_read_at_idx
|
||||
-- Description: Add library_item_user_id_read_at_idx index on library_item table for user_id and read_at
|
||||
|
||||
-- create index for sorting concurrently to avoid locking
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS library_item_user_id_read_at_idx ON omnivore.library_item (user_id, read_at DESC NULLS LAST);
|
||||
9
packages/db/migrations/0156.undo.library_item_user_id_read_at_idx.sql
Executable file
9
packages/db/migrations/0156.undo.library_item_user_id_read_at_idx.sql
Executable file
@ -0,0 +1,9 @@
|
||||
-- Type: UNDO
|
||||
-- Name: library_item_user_id_read_at_idx
|
||||
-- Description: Add library_item_user_id_read_at_idx index on library_item table for user_id and read_at
|
||||
|
||||
BEGIN;
|
||||
|
||||
DROP INDEX IF EXISTS library_item_user_id_read_at_idx;
|
||||
|
||||
COMMIT;
|
||||
6
packages/db/migrations/0157.do.library_item_user_id_word_count_idx.sql
Executable file
6
packages/db/migrations/0157.do.library_item_user_id_word_count_idx.sql
Executable file
@ -0,0 +1,6 @@
|
||||
-- Type: DO
|
||||
-- Name: library_item_user_id_word_count_idx
|
||||
-- Description: Add library_item_user_id_word_count_idx index on library_item table for user_id and word_count
|
||||
|
||||
-- create index for sorting concurrently to avoid locking
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS library_item_user_id_word_count_idx ON omnivore.library_item (user_id, word_count DESC NULLS LAST);
|
||||
9
packages/db/migrations/0157.undo.library_item_user_id_word_count_idx.sql
Executable file
9
packages/db/migrations/0157.undo.library_item_user_id_word_count_idx.sql
Executable file
@ -0,0 +1,9 @@
|
||||
-- Type: UNDO
|
||||
-- Name: library_item_user_id_word_count_idx
|
||||
-- Description: Add library_item_user_id_word_count_idx index on library_item table for user_id and word_count
|
||||
|
||||
BEGIN;
|
||||
|
||||
DROP INDEX IF EXISTS library_item_user_id_word_count_idx;
|
||||
|
||||
COMMIT;
|
||||
34
packages/db/migrations/0158.do.create_label_names_update_trigger.sql
Executable file
34
packages/db/migrations/0158.do.create_label_names_update_trigger.sql
Executable file
@ -0,0 +1,34 @@
|
||||
-- Type: DO
|
||||
-- Name: create_label_names_update_trigger
|
||||
-- Description: Create label_names_update trigger in library_item table
|
||||
|
||||
BEGIN;
|
||||
|
||||
CREATE OR REPLACE FUNCTION update_label_names()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
UPDATE omnivore.library_item
|
||||
SET label_names = array_replace(label_names, OLD.name, NEW.name)
|
||||
WHERE user_id = OLD.user_id AND OLD.name = ANY(label_names);
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- triggers when label name is updated
|
||||
CREATE TRIGGER label_names_update
|
||||
AFTER UPDATE ON omnivore.labels
|
||||
FOR EACH ROW
|
||||
WHEN (OLD.name <> NEW.name)
|
||||
EXECUTE FUNCTION update_label_names();
|
||||
|
||||
-- remove old trigger which is too slow
|
||||
DROP TRIGGER IF EXISTS entity_labels_update ON omnivore.labels;
|
||||
|
||||
DROP FUNCTION IF EXISTS omnivore.update_entity_labels();
|
||||
|
||||
DROP INDEX IF EXISTS omnivore.library_item_saved_at_idx;
|
||||
DROP INDEX IF EXISTS omnivore.library_item_updated_at_idx;
|
||||
DROP INDEX IF EXISTS omnivore.library_item_read_at_idx;;
|
||||
|
||||
COMMIT;
|
||||
34
packages/db/migrations/0158.undo.create_label_names_update_trigger.sql
Executable file
34
packages/db/migrations/0158.undo.create_label_names_update_trigger.sql
Executable file
@ -0,0 +1,34 @@
|
||||
-- Type: UNDO
|
||||
-- Name: create_label_names_update_trigger
|
||||
-- Description: Create label_names_update trigger in library_item table
|
||||
|
||||
BEGIN;
|
||||
|
||||
CREATE INDEX IF NOT EXISTS library_item_saved_at_idx ON omnivore.library_item (saved_at);
|
||||
CREATE INDEX IF NOT EXISTS library_item_updated_at_idx ON omnivore.library_item (updated_at);
|
||||
CREATE INDEX IF NOT EXISTS library_item_read_at_idx ON omnivore.library_item (read_at);
|
||||
|
||||
CREATE OR REPLACE FUNCTION update_entity_labels()
|
||||
RETURNS trigger AS $$
|
||||
BEGIN
|
||||
-- update entity_labels table to trigger update on library_item table
|
||||
UPDATE omnivore.entity_labels
|
||||
SET label_id = NEW.id
|
||||
WHERE label_id = OLD.id;
|
||||
|
||||
return NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- triggers when label name is updated
|
||||
CREATE TRIGGER entity_labels_update
|
||||
AFTER UPDATE ON omnivore.labels
|
||||
FOR EACH ROW
|
||||
WHEN (OLD.name <> NEW.name)
|
||||
EXECUTE FUNCTION update_entity_labels();
|
||||
|
||||
DROP TRIGGER IF EXISTS label_names_update ON omnivore.labels;
|
||||
|
||||
DROP FUNCTION IF EXISTS omnivore.update_label_names();
|
||||
|
||||
COMMIT;
|
||||
Reference in New Issue
Block a user