summaryrefslogtreecommitdiffstats
diff options
context:
space:
mode:
authorEllie Huxtable <ellie@elliehuxtable.com>2022-04-19 18:19:21 +0100
committerGitHub <noreply@github.com>2022-04-19 18:19:21 +0100
commitb98a3788617b79251858efdffa8d9a5dc5e23d63 (patch)
treeb6061201b704bcf108615481f316e79c692c5d37
parent7fe523acd2425b2056096fe1f78486f50d0aa36e (diff)
Add count trigger (#308)
This can be used in a later PR to optimise our database usage significantly. Avoiding COUNT will be fantastic for our CPU usage, and therefore sync times.
-rw-r--r--atuin-server/migrations/20220419082412_add_count_trigger.sql51
1 files changed, 51 insertions, 0 deletions
diff --git a/atuin-server/migrations/20220419082412_add_count_trigger.sql b/atuin-server/migrations/20220419082412_add_count_trigger.sql
new file mode 100644
index 00000000..dd1afa88
--- /dev/null
+++ b/atuin-server/migrations/20220419082412_add_count_trigger.sql
@@ -0,0 +1,51 @@
+-- Prior to this, the count endpoint was super naive and just ran COUNT(1).
+-- This is slow asf. Now that we have an amount of actual traffic,
+-- stop doing that!
+-- This basically maintains a count, so we can read ONE row, instead of ALL the
+-- rows. Much better.
+-- Future optimisation could use some sort of cache so we don't even need to hit
+-- postgres at all.
+
+create table total_history_count_user(
+ id bigserial primary key,
+ user_id bigserial,
+ total integer -- try and avoid using keywords - hence total, not count
+);
+
+create or replace function user_history_count()
+returns trigger as
+$func$
+begin
+ if (TG_OP='INSERT') then
+ update total_history_count_user set total = total + 1 where user_id = new.user_id;
+
+ if not found then
+ insert into total_history_count_user(user_id, total)
+ values (
+ new.user_id,
+ (select count(1) from history where user_id = new.user_id)
+ );
+ end if;
+
+ elsif (TG_OP='DELETE') then
+ update total_history_count_user set total = total - 1 where user_id = new.user_id;
+
+ if not found then
+ insert into total_history_count_user(user_id, total)
+ values (
+ new.user_id,
+ (select count(1) from history where user_id = new.user_id)
+ );
+ end if;
+ end if;
+
+ return NEW; -- this is actually ignored for an after trigger, but oh well
+end;
+$func$
+language plpgsql volatile -- pldfplplpflh
+cost 100; -- default value
+
+create trigger tg_user_history_count
+ after insert or delete on history
+ for each row
+ execute procedure user_history_count();