witten
/
luminotes
Archived
1
0
Fork 0

Major SQL changes to support faster searching, plus changes to model.Note to support the new SQL. Unit tests all pass.

note_current is now a table containing the current versions of each note, rather than a view.
This makes the tsearch2 index much less bloated with duplicate information
This commit is contained in:
Dan Helfman 2008-11-11 21:45:18 -08:00
parent 3c117d05eb
commit 6480b86574
7 changed files with 197 additions and 11 deletions

9
NEWS
View File

@ -1,8 +1,17 @@
1.5.6: 1.5.6:
* Greatly improved the speed of wiki searching for Luminotes Server and
luminotes.com. Also included a section on search performance within the
INSTALL file.
* Added permalinks to blog and discussion forum posts. * Added permalinks to blog and discussion forum posts.
* Fixed a bug in Internet Explorer in which clicking a link sometimes caused * Fixed a bug in Internet Explorer in which clicking a link sometimes caused
the browser window to scroll to the destination note, only to immediately the browser window to scroll to the destination note, only to immediately
scroll back to the clicked link. scroll back to the clicked link.
* NOTE: Luminotes Server only, not Luminotes Desktop: Before you start
Luminotes Server after this upgrade, run the following command as the
PostgreSQL superuser (usually "postgres"):
echo "create language plpgsql;" | psql luminotes
Then, once you start Luminotes Server, be prepared to wait up to several
minutes while the database search indices regenerate.
1.5.5: November 6, 2008 1.5.5: November 6, 2008
* Improved speed of Luminotes Desktop by adding some database indices. This * Improved speed of Luminotes Desktop by adding some database indices. This

View File

@ -148,22 +148,35 @@ class Note( Persistent ):
return "select id from note_current where id = %s;" % quote( object_id ) return "select id from note_current where id = %s;" % quote( object_id )
def sql_exists( self ): def sql_exists( self ):
return Note.sql_id_exists( self.object_id, self.revision ) return Note.sql_id_exists( self.object_id )
def sql_create( self ): def sql_create( self ):
rank = self.__rank rank = self.__rank
if rank is None: if rank is None:
rank = quote( None ) rank = quote( None )
# this relies on a database trigger to copy the new row into the note table
return \ return \
"insert into note ( id, revision, title, contents, notebook_id, startup, deleted_from_id, rank, user_id ) " + \ "insert into note_current ( id, revision, title, contents, notebook_id, startup, deleted_from_id, rank, user_id ) " + \
"values ( %s, %s, %s, %s, %s, %s, %s, %s, %s );" % \ "values ( %s, %s, %s, %s, %s, %s, %s, %s, %s );" % \
( quote( self.object_id ), quote( self.revision ), quote( self.__title ), ( quote( self.object_id ), quote( self.revision ), quote( self.__title ),
quote( self.__contents ), quote( self.__notebook_id ), quote( self.__startup and 't' or 'f' ), quote( self.__contents ), quote( self.__notebook_id ), quote( self.__startup and 't' or 'f' ),
quote( self.__deleted_from_id ), rank, quote( self.user_id ) ) quote( self.__deleted_from_id ), rank, quote( self.user_id ) )
def sql_update( self ): def sql_update( self ):
return self.sql_create() rank = self.__rank
if rank is None:
rank = quote( None )
# this relies on a database trigger to copy the updated row into the note table
return \
"""
update note_current set id = %s, revision = %s, title = %s, contents = %s, notebook_id = %s,
startup = %s, deleted_from_id = %s, rank = %s, user_id = %s where id = %s;
""" % \
( quote( self.object_id ), quote( self.revision ), quote( self.__title ),
quote( self.__contents ), quote( self.__notebook_id ), quote( self.__startup and 't' or 'f' ),
quote( self.__deleted_from_id ), rank, quote( self.user_id ), quote( self.object_id ) )
def sql_load_revisions( self ): def sql_load_revisions( self ):
return """ \ return """ \

View File

@ -1 +1,52 @@
-- Before this will execute, you need to run the following command as the
-- PostgreSQL superuser (usually "postgres"):
-- echo "create language plpgsql;" | psql luminotes
create function log_note_revision() returns trigger as $_$
begin
insert into note values
( NEW.id, NEW.revision, NEW.title, NEW.contents, NEW.notebook_id, NEW.startup,
NEW.deleted_from_id, NEW.rank, NEW.user_id );
return null;
end;
$_$ language plpgsql;
create index session_id_index on session using btree (id); create index session_id_index on session using btree (id);
create index note_user_id_index on note USING btree (user_id);
CREATE TABLE note_current_new (
id text NOT NULL,
revision timestamp with time zone NOT NULL,
title text,
contents text,
notebook_id text,
startup boolean DEFAULT false,
deleted_from_id text,
rank numeric,
search tsvector,
user_id text
);
insert into note_current_new select * from note_current;
drop view note_current;
alter table note_current_new rename to note_current;
ALTER TABLE ONLY note_current ADD CONSTRAINT note_current_pkey PRIMARY KEY (id);
CREATE INDEX note_current_notebook_id_index ON note_current USING btree (notebook_id);
CREATE INDEX note_current_notebook_id_startup_index ON note_current USING btree (notebook_id, startup);
CREATE INDEX note_current_notebook_id_title_index ON note_current USING btree (notebook_id, md5(title));
create index note_current_user_id_index on note_current USING btree (user_id);
drop trigger search_update on note;
drop index search_index;
alter table note drop column search;
update note_current set search = to_tsvector('default', coalesce(title,'') ||' '|| coalesce(contents,'') );
commit;
vacuum full analyze;
start transaction;
create index note_current_search_index on note_current USING gist (search);
commit;
vacuum full analyze;
start transaction;
CREATE TRIGGER search_update
BEFORE INSERT OR UPDATE ON note_current
FOR EACH ROW
EXECUTE PROCEDURE tsearch2('search', 'drop_html_tags', 'title', 'contents');
CREATE TRIGGER note_current_update
AFTER INSERT OR UPDATE ON note_current
FOR EACH ROW
EXECUTE PROCEDURE log_note_revision();

36
model/delta/1.5.6.sqlite Normal file
View File

@ -0,0 +1,36 @@
create index note_user_id_index on note (user_id);
CREATE TABLE note_current_new (
id text NOT NULL,
revision timestamp with time zone NOT NULL,
title text,
contents text,
notebook_id text,
startup boolean DEFAULT false,
deleted_from_id text,
rank numeric,
user_id text
);
insert into note_current_new
select id, revision, title, contents, notebook_id, startup,
deleted_from_id, rank, user_id from note_current;
drop view note_current;
alter table note_current_new rename to note_current;
CREATE INDEX note_current_pkey ON note_current (id);
CREATE INDEX note_current_notebook_id_index ON note_current (notebook_id);
CREATE INDEX note_current_notebook_id_startup_index ON note_current (notebook_id, startup);
CREATE INDEX note_current_notebook_id_title_index ON note_current (notebook_id, title);
create index note_current_user_id_index on note_current (user_id);
create trigger note_current_insert
after insert on note_current
for each row
begin
insert into note values ( NEW.id, NEW.revision, NEW.title, NEW.contents, NEW.notebook_id,
NEW.startup, NEW.deleted_from_id, NEW.rank, null, NEW.user_id );
end;
create trigger note_current_update
after update on note_current
for each row
begin
insert into note values ( NEW.id, NEW.revision, NEW.title, NEW.contents, NEW.notebook_id,
NEW.startup, NEW.deleted_from_id, NEW.rank, null, NEW.user_id );
end;

View File

@ -2,7 +2,7 @@ DROP VIEW luminotes_user_current;
DROP TABLE luminotes_user; DROP TABLE luminotes_user;
DROP VIEW luminotes_group_current; DROP VIEW luminotes_group_current;
DROP TABLE luminotes_group; DROP TABLE luminotes_group;
DROP VIEW note_current; DROP TABLE note_current;
DROP TABLE note; DROP TABLE note;
DROP VIEW notebook_current; DROP VIEW notebook_current;
DROP TABLE notebook; DROP TABLE notebook;
@ -18,3 +18,4 @@ DROP TABLE tag_note;
DROP TABLE schema_version; DROP TABLE schema_version;
DROP TABLE session; DROP TABLE session;
DROP FUNCTION drop_html_tags( text ); DROP FUNCTION drop_html_tags( text );
DROP FUNCTION log_note_revision();

View File

@ -16,6 +16,15 @@ CREATE FUNCTION drop_html_tags(text) RETURNS text
AS $_$select regexp_replace( regexp_replace( $1, '</?(div|p|br|ul|ol|li|h3)( [^>]*?)?/?>', ' ', 'gi' ), '<[^>]+?>', '', 'g' );$_$ AS $_$select regexp_replace( regexp_replace( $1, '</?(div|p|br|ul|ol|li|h3)( [^>]*?)?/?>', ' ', 'gi' ), '<[^>]+?>', '', 'g' );$_$
LANGUAGE sql; LANGUAGE sql;
ALTER FUNCTION public.drop_html_tags(text) OWNER TO luminotes; ALTER FUNCTION public.drop_html_tags(text) OWNER TO luminotes;
create function log_note_revision() returns trigger as $_$
begin
insert into note values
( NEW.id, NEW.revision, NEW.title, NEW.contents, NEW.notebook_id, NEW.startup,
NEW.deleted_from_id, NEW.rank, NEW.user_id );
return null;
end;
$_$ language plpgsql;
ALTER FUNCTION public.log_note_revision() OWNER TO luminotes;
CREATE TABLE file ( CREATE TABLE file (
id text NOT NULL, id text NOT NULL,
revision timestamp with time zone, revision timestamp with time zone,
@ -92,12 +101,21 @@ CREATE TABLE note (
startup boolean DEFAULT false, startup boolean DEFAULT false,
deleted_from_id text, deleted_from_id text,
rank numeric, rank numeric,
search tsvector,
user_id text user_id text
); );
ALTER TABLE public.note OWNER TO luminotes; ALTER TABLE public.note OWNER TO luminotes;
CREATE VIEW note_current AS CREATE TABLE note_current (
SELECT note.id, note.revision, note.title, note.contents, note.notebook_id, note.startup, note.deleted_from_id, note.rank, note.search, note.user_id FROM note WHERE (note.revision IN (SELECT max(sub_note.revision) AS max FROM note sub_note WHERE (sub_note.id = note.id))); id text NOT NULL,
revision timestamp with time zone NOT NULL,
title text,
contents text,
notebook_id text,
startup boolean DEFAULT false,
deleted_from_id text,
rank numeric,
search tsvector,
user_id text
);
ALTER TABLE public.note_current OWNER TO luminotes; ALTER TABLE public.note_current OWNER TO luminotes;
CREATE TABLE notebook ( CREATE TABLE notebook (
id text NOT NULL, id text NOT NULL,
@ -170,6 +188,9 @@ ALTER TABLE ONLY luminotes_user
ALTER TABLE ONLY note ALTER TABLE ONLY note
ADD CONSTRAINT note_pkey PRIMARY KEY (id, revision); ADD CONSTRAINT note_pkey PRIMARY KEY (id, revision);
ALTER TABLE ONLY note_current
ADD CONSTRAINT note_pkey PRIMARY KEY (id);
ALTER TABLE ONLY notebook ALTER TABLE ONLY notebook
ADD CONSTRAINT notebook_pkey PRIMARY KEY (id, revision); ADD CONSTRAINT notebook_pkey PRIMARY KEY (id, revision);
@ -202,17 +223,34 @@ CREATE INDEX note_notebook_id_startup_index ON note USING btree (notebook_id, st
CREATE INDEX note_notebook_id_title_index ON note USING btree (notebook_id, md5(title)); CREATE INDEX note_notebook_id_title_index ON note USING btree (notebook_id, md5(title));
CREATE INDEX note_user_id_index ON note USING btree (user_id);
CREATE INDEX note_current_notebook_id_index ON note_current USING btree (notebook_id);
CREATE INDEX note_current_notebook_id_startup_index ON note_current USING btree (notebook_id, startup);
CREATE INDEX note_current_notebook_id_title_index ON note_current USING btree (notebook_id, md5(title));
CREATE INDEX note_current_user_id_index ON note_current USING btree (user_id);
CREATE INDEX note_current_search_index ON note_current USING gist (search);
CREATE INDEX password_reset_email_address_index ON password_reset USING btree (email_address); CREATE INDEX password_reset_email_address_index ON password_reset USING btree (email_address);
CREATE INDEX download_access_transaction_id_index ON download_access USING btree (transaction_id); CREATE INDEX download_access_transaction_id_index ON download_access USING btree (transaction_id);
CREATE INDEX search_index ON note USING gist (search); CREATE INDEX session_id_index on session using btree (id);
CREATE TRIGGER search_update CREATE TRIGGER search_update
BEFORE INSERT OR UPDATE ON note BEFORE INSERT OR UPDATE ON note_current
FOR EACH ROW FOR EACH ROW
EXECUTE PROCEDURE tsearch2('search', 'drop_html_tags', 'title', 'contents'); EXECUTE PROCEDURE tsearch2('search', 'drop_html_tags', 'title', 'contents');
CREATE TRIGGER note_current_update
AFTER INSERT OR UPDATE ON note_current
FOR EACH ROW
EXECUTE PROCEDURE log_note_revision();
REVOKE ALL ON SCHEMA public FROM PUBLIC; REVOKE ALL ON SCHEMA public FROM PUBLIC;
REVOKE ALL ON SCHEMA public FROM postgres; REVOKE ALL ON SCHEMA public FROM postgres;
GRANT ALL ON SCHEMA public TO postgres; GRANT ALL ON SCHEMA public TO postgres;

View File

@ -81,8 +81,18 @@ CREATE TABLE note (
user_id text user_id text
); );
CREATE VIEW note_current AS CREATE TABLE note_current (
SELECT id, revision, title, contents, notebook_id, startup, deleted_from_id, rank, search, user_id FROM note WHERE (note.revision IN (SELECT max(sub_note.revision) AS max FROM note sub_note WHERE (sub_note.id = note.id))); id text NOT NULL,
revision timestamp with time zone NOT NULL,
title text,
contents text,
notebook_id text,
startup boolean DEFAULT false,
deleted_from_id text,
rank numeric,
user_id text
);
CREATE TABLE notebook ( CREATE TABLE notebook (
id text NOT NULL, id text NOT NULL,
@ -139,6 +149,8 @@ CREATE INDEX luminotes_user_pkey ON luminotes_user (id, revision);
CREATE INDEX note_pkey ON note (id, revision); CREATE INDEX note_pkey ON note (id, revision);
CREATE INDEX note_current_pkey ON note (id);
CREATE INDEX notebook_pkey ON notebook (id, revision); CREATE INDEX notebook_pkey ON notebook (id, revision);
CREATE INDEX password_reset_pkey ON password_reset (id); CREATE INDEX password_reset_pkey ON password_reset (id);
@ -167,6 +179,16 @@ CREATE INDEX note_notebook_id_startup_index ON note (notebook_id, startup);
CREATE INDEX note_notebook_id_title_index ON note (notebook_id, title); CREATE INDEX note_notebook_id_title_index ON note (notebook_id, title);
CREATE INDEX note_user_id_index ON note (user_id);
CREATE INDEX note_current_notebook_id_index ON note_current (notebook_id);
CREATE INDEX note_current_notebook_id_startup_index ON note_current (notebook_id, startup);
CREATE INDEX note_current_notebook_id_title_index ON note_current (notebook_id, title);
CREATE INDEX note_current_user_id_index ON note_current (user_id);
CREATE INDEX password_reset_id_index ON password_reset (id); CREATE INDEX password_reset_id_index ON password_reset (id);
CREATE INDEX password_reset_email_address_index ON password_reset (email_address); CREATE INDEX password_reset_email_address_index ON password_reset (email_address);
@ -176,3 +198,19 @@ CREATE INDEX download_access_id_index ON password_reset (id);
CREATE INDEX download_access_transaction_id_index ON download_access (transaction_id); CREATE INDEX download_access_transaction_id_index ON download_access (transaction_id);
CREATE INDEX search_index ON note (search); CREATE INDEX search_index ON note (search);
create trigger note_current_insert
after insert on note_current
for each row
begin
insert into note values ( NEW.id, NEW.revision, NEW.title, NEW.contents, NEW.notebook_id,
NEW.startup, NEW.deleted_from_id, NEW.rank, null, NEW.user_id );
end;
create trigger note_current_update
after update on note_current
for each row
begin
insert into note values ( NEW.id, NEW.revision, NEW.title, NEW.contents, NEW.notebook_id,
NEW.startup, NEW.deleted_from_id, NEW.rank, null, NEW.user_id );
end;