Skip to content

Commit

Permalink
database: rank: DDL
Browse files Browse the repository at this point in the history
  • Loading branch information
ice-dionysos committed Feb 16, 2025
1 parent 4420ffd commit 64d8b1a
Show file tree
Hide file tree
Showing 11 changed files with 509 additions and 42 deletions.
2 changes: 2 additions & 0 deletions .gitignore
Original file line number Diff line number Diff line change
Expand Up @@ -39,3 +39,5 @@ subzero-ion-connect-keygen
!subzero-ion-connect-authgen/
!subzero-ion-connect-indexer/
!subzero-ion-connect-keygen/

.test-uploads2
9 changes: 5 additions & 4 deletions Makefile
Original file line number Diff line number Diff line change
Expand Up @@ -8,6 +8,7 @@ CGO_ENABLED ?= 1
GOOS ?=
GOARCH ?=
SERVICE_NAME ?=
TAGS := go_json,linux,sqlite_stat4,sqlite_icu,sqlite_fts5,sqlite_math_functions

export CGO_ENABLED GOOS GOARCH SERVICE_NAME

Expand Down Expand Up @@ -60,7 +61,7 @@ checkGenerated: generate
true;

build-all@ci/cd:
go build -tags "go_json linux sqlite_stat4 sqlite_icu sqlite_fts5" -a -v -race ./...
go build -tags $(TAGS) -a -v -race ./...

build: build-all@ci/cd

Expand Down Expand Up @@ -90,11 +91,11 @@ coverage: $(COVERAGE_FILE)

test@ci/cd:
# TODO make -race work
go test -timeout 20m -tags "go_json test linux sqlite_stat4 sqlite_icu sqlite_fts5" -v -cover -coverprofile=$(COVERAGE_FILE) -covermode atomic
go test -timeout 20m -tags test,$(TAGS) -v -cover -coverprofile=$(COVERAGE_FILE) -covermode atomic

benchmark@ci/cd:
# TODO make -race work
go test -timeout 20m -tags "go_json test linux sqlite_stat4 sqlite_icu sqlite_fts5" -run=^$ -v -bench=. -benchmem -benchtime 10s
go test -timeout 20m -tags test,$(TAGS) -run=^$ -v -bench=. -benchmem -benchtime 10s

benchmark:
set -xe; \
Expand Down Expand Up @@ -164,7 +165,7 @@ buildAllBinaries:
binary-specific-service:
set -xe; \
echo "$@: $(SERVICE_NAME) / $(GOOS) / $(GOARCH)" ; \
go build -tags "go_json linux sqlite_stat4 sqlite_icu sqlite_fts5" -a -v -o ./cmd/$${SERVICE_NAME}/bin ./cmd/$${SERVICE_NAME}; \
go build -tags $(TAGS) -a -v -o ./cmd/$${SERVICE_NAME}/bin ./cmd/$${SERVICE_NAME}; \
cp ./cmd/$${SERVICE_NAME}/bin ./$${SERVICE_NAME}.$${GOOS}.$${GOARCH}.bin; \

all: checkLicense checkModVersion checkIfAllDependenciesAreUpToDate checkGenerated build test coverage benchmark clean
Expand Down
220 changes: 220 additions & 0 deletions database/query/DDL.sql
Original file line number Diff line number Diff line change
@@ -1,11 +1,17 @@
-- SPDX-License-Identifier: ice License 1.0

-- system_kind:
-- 1: quote
-- 2: comment_root
-- 3: comment_reply

CREATE TABLE IF NOT EXISTS events
(
rid integer primary key,
kind integer not null,
created_at integer not null,
system_created_at integer not null,
system_kind integer,
id text not null UNIQUE,
pubkey text not null,
master_pubkey text not null,
Expand All @@ -17,6 +23,12 @@ CREATE TABLE IF NOT EXISTS events
d_tag text not null DEFAULT '',
h_tag text not null DEFAULT '',
reference_id text references events (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
address text not null generated always as (
CASE
WHEN (10000 <= kind AND kind < 20000) OR kind = 0 OR kind = 3 THEN concat(coalesce(kind,0), ':', coalesce(master_pubkey,pubkey,''),':')
WHEN 30000 <= kind AND kind < 40000 THEN concat(coalesce(kind,0), ':', coalesce(master_pubkey,pubkey,''),':',coalesce(d_tag,''))
ELSE id
END) VIRTUAL,
tags text not null DEFAULT '[]',
deleted integer not null default 0,
hidden integer not null default 0
Expand Down Expand Up @@ -59,6 +71,7 @@ CREATE INDEX IF NOT EXISTS idx_events_system_created_at_id_created_at
CREATE INDEX IF NOT EXISTS idx_events_reference_id_system_created_at ON events(reference_id, system_created_at DESC) where hidden = 0;
CREATE INDEX IF NOT EXISTS idx_events_pubkey_master_pubkey_system_created_at ON events(pubkey, master_pubkey, system_created_at DESC) where hidden = 0;
CREATE INDEX IF NOT EXISTS idx_events_h_tag_system_created_at ON events(h_tag, system_created_at DESC) where kind = 1753;
CREATE INDEX IF NOT EXISTS idx_events_address ON events(address);

-- Special index for inserts.
CREATE INDEX IF NOT EXISTS idx_events_reference_id ON events(reference_id);
Expand Down Expand Up @@ -543,4 +556,211 @@ update events
set content_metadata = subzero_nostr_generate_content_metadata(kind, content, tags)
where ((kind = 0 and json_valid(content)) or kind IN (1, 30175, 30023) or kind = 1063) AND content_metadata = '';
--------
CREATE TABLE IF NOT EXISTS ranked_events
(
event_rid integer not null primary key references events (rid) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
event_kind integer not null,
event_created_at integer not null,
points integer not null,
score real not null
) strict, WITHOUT ROWID;
--------
create index if not exists ranked_events_score_ix on ranked_events(score desc);
create index if not exists ranked_events_created_at_score_ix on ranked_events(event_created_at desc, score desc);
--------
drop trigger if exists trigger_events_after_insert_score_add;
create trigger if not exists trigger_events_after_insert_score_add
after insert
ON events
for each row
when NEW.kind in (1, 6, 7, 16, 30023, 30175) and NEW.hidden = 0 and NEW.deleted = 0
begin
insert into ranked_events(event_rid, event_kind, event_created_at, points, score)
with cte as (
select
json_extract(je.value, '$[1]') as event_address
from
json_each(NEW.tags) je
where
json_extract(je.value, '$[0]') in ('a', 'e', 'q', 'Q')
and (NEW.system_kind is null or case
when NEW.system_kind = 2 then json_extract(je.value, '$[3]') = 'root'
when NEW.system_kind = 3 then false -- ignore replies
else true
end)
)
select
e.rid,
e.kind,
e.created_at,
case
when NEW.kind = 7 then 1 -- like
when NEW.kind in (6, 16) then 3 -- repost
when NEW.system_kind is not null and NEW.system_kind = 1 then 4 -- quote
when NEW.system_kind is not null and NEW.system_kind = 2 then 2 -- top level comment (root)
else 0
end,
(round(( case
when NEW.kind = 7 then 1
when NEW.kind in (6, 16) then 3
when NEW.system_kind is not null and NEW.system_kind = 1 then 4
when NEW.system_kind is not null and NEW.system_kind = 2 then 2
else 0
end / power((1 + (unixepoch() - min(unixepoch(), e.created_at))/3600.0), 0.9)), 4))
from
events e
inner join cte on e.address = cte.event_address
where
e.hidden = 0
and e.deleted = 0
and e.id = e.h_tag
and e.created_at > 0
and e.kind in (1, 30023, 30175)
and (NEW.system_kind is null or NEW.system_kind != 3)
on conflict do update
set
points = points + excluded.points,
score = (round((points + excluded.points / power((1 + (unixepoch() - min(unixepoch(), event_created_at))/3600.0), 0.9)), 4));
end;
--------
drop trigger if exists trigger_events_after_update_score_add;
create trigger if not exists trigger_events_after_update_score_add
after update
ON events
for each row
when ((NEW.kind in (1, 6, 7, 16, 30023, 30175)) and (NEW.hidden = 0) and (NEW.tags != OLD.tags)) OR (OLD.deleted != NEW.deleted)
begin
update ranked_events
set
points = points - case
when OLD.kind = 7 then 1 -- like
when OLD.kind in (6, 16) then 3 -- repost
when OLD.system_kind is not null and OLD.system_kind = 1 then 4 -- quote
when OLD.system_kind is not null and OLD.system_kind = 2 then 2 -- top level comment (root)
else 0
end,
score = (round((points - case
when OLD.kind = 7 then 1
when OLD.kind in (6, 16) then 3
when OLD.system_kind is not null and OLD.system_kind = 1 then 4
when OLD.system_kind is not null and OLD.system_kind = 2 then 2
else 0
end) / power((1 + (unixepoch() - min(unixepoch(), event_created_at))/3600.0), 0.9), 4))
where exists (
select 1
from json_each(OLD.tags) je
where json_extract(je.value, '$[0]') in ('a', 'e', 'q', 'Q')
and ranked_events.event_rid in (
select rid
from events e
where e.address = json_extract(je.value, '$[1]')
and e.hidden = 0
and e.id = e.h_tag
and e.created_at > 0
and e.kind in (1, 30023, 30175)
and (OLD.system_kind is null or OLD.system_kind != 3)
and (OLD.system_kind is null or case
when OLD.system_kind = 2 then json_extract(je.value, '$[3]') = 'root'
when OLD.system_kind = 3 then false
else true
end)
)
);
insert into ranked_events(event_rid, event_kind, event_created_at, points, score)
with cte as (
select
json_extract(je.value, '$[1]') as event_address
from
json_each(NEW.tags) je
where
json_extract(je.value, '$[0]') in ('a', 'e', 'q', 'Q')
and (NEW.system_kind is null or case
when NEW.system_kind = 2 then json_extract(je.value, '$[3]') = 'root'
when NEW.system_kind = 3 then false -- ignore replies
else true
end)
)
select
e.rid,
e.kind,
e.created_at,
case
when NEW.kind = 7 then 1 -- like
when NEW.kind in (6, 16) then 3 -- repost
when NEW.system_kind is not null and NEW.system_kind = 1 then 4 -- quote
when NEW.system_kind is not null and NEW.system_kind = 2 then 2 -- top level comment (root)
else 0
end,
(round(( case
when NEW.kind = 7 then 1
when NEW.kind in (6, 16) then 3
when NEW.system_kind is not null and NEW.system_kind = 1 then 4
when NEW.system_kind is not null and NEW.system_kind = 2 then 2
else 0
end / power((1 + (unixepoch() - min(unixepoch(), e.created_at))/3600.0), 0.9)), 4))
from
events e
inner join cte on e.address = cte.event_address
where
e.hidden = 0
and e.deleted = 0
and e.id = e.h_tag
and e.created_at > 0
and e.kind in (1, 30023, 30175)
and NEW.deleted = 0
and (NEW.system_kind is null or NEW.system_kind != 3)
on conflict do update
set
points = points + excluded.points,
score = (round((points + excluded.points / power((1 + (unixepoch() - min(unixepoch(), event_created_at))/3600.0), 0.9)), 4));
delete from ranked_events where points <= 0;
end;
--------
drop trigger if exists trigger_events_after_delete_score_dec;
create trigger if not exists trigger_events_after_delete_score_dec
after delete
ON events
for each row
when OLD.kind in (1, 6, 7, 16, 30023, 30175) and OLD.hidden = 0 and OLD.deleted = 0
begin
update ranked_events
set
points = points - case
when OLD.kind = 7 then 1 -- like
when OLD.kind in (6, 16) then 3 -- repost
when OLD.system_kind is not null and OLD.system_kind = 1 then 4 -- quote
when OLD.system_kind is not null and OLD.system_kind = 2 then 2 -- top level comment (root)
else 0
end,
score = (round((points - case
when OLD.kind = 7 then 1
when OLD.kind in (6, 16) then 3
when OLD.system_kind is not null and OLD.system_kind = 1 then 4
when OLD.system_kind is not null and OLD.system_kind = 2 then 2
else 0
end) / power((1 + (unixepoch() - min(unixepoch(), event_created_at))/3600.0), 0.9), 4))
where exists (
select 1
from json_each(OLD.tags) je
where json_extract(je.value, '$[0]') in ('a', 'e', 'q', 'Q')
and ranked_events.event_rid in (
select rid
from events e
where e.address = json_extract(je.value, '$[1]')
and e.hidden = 0
and e.deleted = 0
and e.id = e.h_tag
and e.created_at > 0
and e.kind in (1, 30023, 30175)
and (OLD.system_kind is null or OLD.system_kind != 3)
and (OLD.system_kind is null or case
when OLD.system_kind = 2 then json_extract(je.value, '$[3]') = 'root'
when OLD.system_kind = 3 then false
else true
end)
)
);
delete from ranked_events where points <= 0;
end;
--------
PRAGMA foreign_keys = on;
10 changes: 6 additions & 4 deletions database/query/Makefile
Original file line number Diff line number Diff line change
Expand Up @@ -2,13 +2,15 @@ export TESTDB := .testdata/testdb_3M.sqlite3

.PHONY: test gendb benchdb_select benchdb_insert all

TAGS := test,sqlite_fts5,sqlite_math_functions

all: test

gendb:
GENDB=yes go test -v -timeout=10h -run 'TestGenerateDataForFile3M' -tags "sqlite_fts5"
GENDB=yes go test -tags $(TAGS) -v -timeout=10h -run 'TestGenerateDataForFile3M'

benchdb_select: $(TESTDB)
BENCHDB=yes go test -v -timeout=10h -run=^$$ -bench=^BenchmarkSelectBy -benchtime=20x -count 20 -benchmem . | tee $@_current.txt
BENCHDB=yes go test -tags $(TAGS) -v -timeout=10h -run=^$$ -bench=^BenchmarkSelectBy -benchtime=20x -count 20 -benchmem . | tee $@_current.txt

BENCH_INSERT_P_LIST := 1 10 100
BENCH_INSERT_DB_LIST := testdb_3M
Expand All @@ -21,9 +23,9 @@ benchdb_insert:
BENCHDB=yes \
BENCHDB_PARALLELISM=$${p} \
TESTDB=".testdata/$${db}.sqlite3" \
go test -v -timeout=10h -run=^$$ -bench=^BenchmarkEventInsert -benchtime=30s -count 1 -benchmem . | tee $@_current.txt; \
go test -tags $(TAGS) -v -timeout=10h -run=^$$ -bench=^BenchmarkEventInsert -benchtime=30s -count 1 -benchmem . | tee $@_current.txt; \
done | tee $${db}_results.txt; \
done;

test:
go test -v -timeout=10h
go test -tags $(TAGS) -v -timeout=10h
35 changes: 24 additions & 11 deletions database/query/client.go
Original file line number Diff line number Diff line change
Expand Up @@ -114,6 +114,8 @@ func openDatabase(target string, runDDL bool) *dbClient {
out = "created_at"
case "systemcreatedat":
out = "system_created_at"
case "systemkind":
out = "system_kind"
case "referenceid":
out = "reference_id"
case "sigalg":
Expand Down Expand Up @@ -141,26 +143,37 @@ func openDatabase(target string, runDDL bool) *dbClient {
for _, statement := range strings.Split(ddl, "--------") {
tx.MustExec(statement)
}
if err := client.alterEventsTable(tx); err != nil {
panic(err)
}
client.alterEventsTable(tx)
tx.Commit()
}

return client
}

func (db *dbClient) alterEventsTable(tx *sqlx.Tx) error {
var doAlter bool

err := tx.QueryRowx("SELECT not exists (select name from pragma_table_info('events') WHERE name = 'deleted')").Scan(&doAlter)
if err != nil || !doAlter {
return err
func (db *dbClient) alterEventsTable(tx *sqlx.Tx) {
columns := map[string]string{
"system_kind": "ALTER TABLE events ADD COLUMN system_kind integer",
"deleted": "ALTER TABLE events ADD COLUMN deleted integer not null DEFAULT 0",
"address": `ALTER TABLE events ADD COLUMN address text not null generated always as (
CASE
WHEN (10000 <= kind AND kind < 20000) OR kind = 0 OR kind = 3 THEN concat(coalesce(kind,0), ':', coalesce(master_pubkey,pubkey,''),':')
WHEN 30000 <= kind AND kind < 40000 THEN concat(coalesce(kind,0), ':', coalesce(master_pubkey,pubkey,''),':',coalesce(d_tag,''))
ELSE id
END) VIRTUAL`,
}

_, err = tx.Exec("ALTER TABLE events ADD COLUMN deleted integer not null DEFAULT 0")
for column, statement := range columns {
var doAlter bool

err := tx.QueryRow("SELECT not exists (select name from pragma_table_xinfo('events') WHERE name = $1)", column).Scan(&doAlter)
if err != nil {
panic("failed to check if column " + column + " exists: " + err.Error())
}

return err
if doAlter {
tx.MustExec(statement)
}
}
}

func (db *dbClient) WithRelayURL(relayURL string) *dbClient {
Expand Down
Loading

0 comments on commit 64d8b1a

Please sign in to comment.