summaryrefslogtreecommitdiffstats
path: root/askbot/search
diff options
context:
space:
mode:
authorAdolfo Fitoria <adolfo.fitoria@gmail.com>2012-10-02 09:58:07 -0600
committerAdolfo Fitoria <adolfo.fitoria@gmail.com>2012-10-02 10:40:25 -0600
commit2a398269923b779b63ca8432b6d98dc2ae6c6a50 (patch)
tree3b946679a96442d2b0d3081a40624db124a7c1a9 /askbot/search
parentf1eda1494b753b052c82811419aff8380520ec85 (diff)
parent8559f348eab0f59aa32d037a43d4a730112bab3c (diff)
downloadaskbot-2a398269923b779b63ca8432b6d98dc2ae6c6a50.tar.gz
askbot-2a398269923b779b63ca8432b6d98dc2ae6c6a50.tar.bz2
askbot-2a398269923b779b63ca8432b6d98dc2ae6c6a50.zip
Merge branch 'master' into haystack
Conflicts: askbot/models/__init__.py askbot/models/question.py askbot/setup_templates/settings.py askbot/setup_templates/settings.py.mustache askbot/tests/__init__.py askbot/tests/badge_tests.py askbot/tests/db_api_tests.py askbot/views/commands.py askbot/views/readers.py askbot/views/users.py askbot/views/writers.py
Diffstat (limited to 'askbot/search')
-rw-r--r--askbot/search/postgresql/thread_and_post_models_05222012.plsql225
-rw-r--r--askbot/search/postgresql/user_profile_search_08312012.plsql93
-rw-r--r--askbot/search/state_manager.py4
3 files changed, 322 insertions, 0 deletions
diff --git a/askbot/search/postgresql/thread_and_post_models_05222012.plsql b/askbot/search/postgresql/thread_and_post_models_05222012.plsql
new file mode 100644
index 00000000..1fe12625
--- /dev/null
+++ b/askbot/search/postgresql/thread_and_post_models_05222012.plsql
@@ -0,0 +1,225 @@
+/* function testing for existence of a column in a table
+ if table does not exists, function will return "false" */
+CREATE OR REPLACE FUNCTION column_exists(colname text, tablename text)
+RETURNS boolean AS
+$$
+DECLARE
+ q text;
+ onerow record;
+BEGIN
+
+ q = 'SELECT attname FROM pg_attribute WHERE attrelid = ( SELECT oid FROM pg_class WHERE relname = '''||tablename||''') AND attname = '''||colname||'''';
+
+ FOR onerow IN EXECUTE q LOOP
+ RETURN true;
+ END LOOP;
+
+ RETURN false;
+END;
+$$ LANGUAGE plpgsql;
+
+/* function adding tsvector column to table if it does not exists */
+CREATE OR REPLACE FUNCTION add_tsvector_column(colname text, tablename text)
+RETURNS boolean AS
+$$
+DECLARE
+ q text;
+BEGIN
+ IF NOT column_exists(colname, tablename) THEN
+ q = 'ALTER TABLE ' || tablename || ' ADD COLUMN ' || colname || ' tsvector';
+ EXECUTE q;
+ RETURN true;
+ ELSE
+ q = 'UPDATE ' || tablename || ' SET ' || colname || '=NULL';
+ EXECUTE q;
+ RETURN false;
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+
+/* aggregate function that concatenates tsvectors */
+CREATE OR REPLACE FUNCTION tsv_add(tsv1 tsvector, tsv2 tsvector)
+RETURNS tsvector AS
+$$
+BEGIN
+ RETURN tsv1 || tsv2;
+END;
+$$ LANGUAGE plpgsql;
+
+CREATE OR REPLACE FUNCTION setup_aggregates() RETURNS boolean AS
+$$
+DECLARE
+ onerow record;
+BEGIN
+ FOR onerow IN SELECT * FROM pg_proc WHERE proname = 'concat_tsvectors' AND proisagg LOOP
+ DROP AGGREGATE concat_tsvectors(tsvector);
+ END LOOP;
+ CREATE AGGREGATE concat_tsvectors (
+ BASETYPE = tsvector,
+ SFUNC = tsv_add,
+ STYPE = tsvector,
+ INITCOND = ''
+ );
+ RETURN true;
+END;
+$$ LANGUAGE plpgsql;
+
+SELECT setup_aggregates();
+
+/* calculates text search vector for the individual thread row
+DOES not include question body post, answers or comments */
+CREATE OR REPLACE FUNCTION get_thread_tsv(title text, tagnames text)
+RETURNS tsvector AS
+$$
+BEGIN
+ /* todo add weight depending on votes */
+ RETURN setweight(to_tsvector('english', coalesce(title, '')), 'A') ||
+ setweight(to_tsvector('english', coalesce(tagnames, '')), 'A');
+END;
+$$ LANGUAGE plpgsql;
+
+/* calculates text seanch vector for the individual question row */
+CREATE OR REPLACE FUNCTION get_post_tsv(text text, post_type text)
+RETURNS tsvector AS
+$$
+BEGIN
+ /* todo adjust weights to reflect votes */
+ IF post_type='question' THEN
+ RETURN setweight(to_tsvector('english', coalesce(text, '')), 'B');
+ ELSIF post_type='answer' THEN
+ /* todo reflect whether the answer acepted or has many points */
+ RETURN setweight(to_tsvector('english', coalesce(text, '')), 'C');
+ ELSIF post_type='comment' THEN
+ RETURN setweight(to_tsvector('english', coalesce(text, '')), 'D');
+ ELSE
+ RETURN to_tsvector('');
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+
+/* calculates text search vector for the question body part by thread id
+here we extract question title and the text by thread_id and then
+calculate the text search vector. In the future question
+title will be moved to the askbot_thread table and this function
+will be simpler.
+*/
+CREATE OR REPLACE FUNCTION get_thread_question_tsv(thread_id integer)
+RETURNS tsvector AS
+$$
+DECLARE
+ query text;
+ onerow record;
+BEGIN
+ query = 'SELECT text FROM askbot_post WHERE thread_id=' || thread_id ||
+ ' AND post_type=''question'' AND deleted=false';
+ FOR onerow in EXECUTE query LOOP
+ RETURN get_post_tsv(onerow.text, 'question');
+ END LOOP;
+ RETURN to_tsvector('');
+END;
+$$ LANGUAGE plpgsql;
+
+DROP FUNCTION IF EXISTS get_dependent_comments_tsv(object_id integer, tablename text);
+CREATE OR REPLACE FUNCTION get_dependent_comments_tsv(parent_id integer)
+RETURNS tsvector AS
+$$
+DECLARE
+ query text;
+ onerow record;
+BEGIN
+ query = 'SELECT concat_tsvectors(text_search_vector) FROM askbot_post' ||
+ ' WHERE parent_id=' || parent_id ||
+ ' AND post_type=''comment'' AND deleted=false';
+ FOR onerow IN EXECUTE query LOOP
+ RETURN onerow.concat_tsvectors;
+ END LOOP;
+ RETURN to_tsvector('');
+END;
+$$ LANGUAGE plpgsql;
+
+DROP FUNCTION IF EXISTS get_dependent_answers_tsv(question_id integer);
+CREATE OR REPLACE FUNCTION get_dependent_answers_tsv(thread_id integer)
+RETURNS tsvector AS
+$$
+DECLARE
+ query text;
+ onerow record;
+BEGIN
+ query = 'SELECT concat_tsvectors(text_search_vector) ' ||
+ 'FROM askbot_post WHERE thread_id = ' || thread_id ||
+ ' AND deleted=false';
+ FOR onerow IN EXECUTE query LOOP
+ RETURN onerow.concat_tsvectors;
+ END LOOP;
+ RETURN to_tsvector('');
+END;
+$$ LANGUAGE plpgsql;
+
+/* create tsvector columns in the content tables */
+SELECT add_tsvector_column('text_search_vector', 'askbot_thread');
+SELECT add_tsvector_column('text_search_vector', 'askbot_post');
+
+/* populate tsvectors with data */
+-- post tsvectors
+UPDATE askbot_post set text_search_vector = get_post_tsv(text, 'comment') WHERE post_type='comment';
+UPDATE askbot_post SET text_search_vector = get_post_tsv(text, 'answer') WHERE post_type='answer';
+UPDATE askbot_post SET text_search_vector = get_post_tsv(text, 'question') WHERE post_type='question';
+UPDATE askbot_post as q SET text_search_vector = text_search_vector ||
+ get_dependent_comments_tsv(q.id) WHERE post_type IN ('question', 'answer');
+
+--thread tsvector
+UPDATE askbot_thread SET text_search_vector = get_thread_tsv(title, tagnames);
+UPDATE askbot_thread as t SET text_search_vector = text_search_vector ||
+ get_dependent_answers_tsv(t.id) ||
+ get_thread_question_tsv(t.id);
+
+/* one trigger per table for tsv updates */
+
+/* set up update triggers */
+CREATE OR REPLACE FUNCTION thread_update_trigger() RETURNS trigger AS
+$$
+BEGIN
+ new.text_search_vector = get_thread_tsv(new.title, new.tagnames) ||
+ get_thread_question_tsv(new.id) ||
+ get_dependent_answers_tsv(new.id);
+ RETURN new;
+END;
+$$ LANGUAGE plpgsql;
+DROP TRIGGER IF EXISTS thread_search_vector_update_trigger on askbot_thread;
+CREATE TRIGGER thread_search_vector_update_trigger
+BEFORE UPDATE ON askbot_thread FOR EACH ROW EXECUTE PROCEDURE thread_update_trigger();
+
+CREATE OR REPLACE FUNCTION thread_insert_trigger() RETURNS trigger AS
+$$
+BEGIN
+ new.text_search_vector = get_thread_tsv(new.title, new.tagnames);
+ RETURN new;
+END;
+$$ LANGUAGE plpgsql;
+DROP TRIGGER IF EXISTS thread_search_vector_insert_trigger on askbot_thread;
+CREATE TRIGGER thread_search_vector_insert_trigger
+BEFORE INSERT ON askbot_thread FOR EACH ROW EXECUTE PROCEDURE thread_insert_trigger();
+
+/* post trigger */
+CREATE OR REPLACE FUNCTION post_trigger() RETURNS trigger AS
+$$
+BEGIN
+ IF new.post_type = 'question' THEN
+ new.text_search_vector = get_post_tsv(new.text, 'question') ||
+ get_dependent_comments_tsv(new.id);
+ ELSIF new.post_type = 'answer' THEN
+ new.text_search_vector = get_post_tsv(new.text, 'answer') ||
+ get_dependent_comments_tsv(new.id);
+ ELSIF new.post_type = 'comment' THEN
+ new.text_search_vector = get_post_tsv(new.text, 'comment');
+ END IF;
+ UPDATE askbot_thread SET id=new.thread_id WHERE id=new.thread_id;
+ return new;
+END;
+$$ LANGUAGE plpgsql;
+DROP TRIGGER IF EXISTS post_search_vector_update_trigger on askbot_post;
+CREATE TRIGGER post_search_vector_update_trigger
+BEFORE INSERT OR UPDATE ON askbot_post FOR EACH ROW EXECUTE PROCEDURE post_trigger();
+
+DROP INDEX IF EXISTS askbot_search_idx;
+CREATE INDEX askbot_search_idx ON askbot_thread USING gin(text_search_vector);
diff --git a/askbot/search/postgresql/user_profile_search_08312012.plsql b/askbot/search/postgresql/user_profile_search_08312012.plsql
new file mode 100644
index 00000000..90b73148
--- /dev/null
+++ b/askbot/search/postgresql/user_profile_search_08312012.plsql
@@ -0,0 +1,93 @@
+/*
+Script depends on functions defined for general askbot full text search.
+to_tsvector(), add_tsvector_column()
+
+calculates text search vector for the user profile
+the searched fields are:
+1) user name
+2) user profile
+3) group names - for groups to which user belongs
+*/
+CREATE OR REPLACE FUNCTION get_auth_user_tsv(user_id integer)
+RETURNS tsvector AS
+$$
+DECLARE
+ group_query text;
+ user_query text;
+ onerow record;
+ tsv tsvector;
+BEGIN
+ group_query =
+ 'SELECT user_group.name as group_name ' ||
+ 'FROM auth_group AS user_group ' ||
+ 'INNER JOIN auth_user_groups AS gm ' ||
+ 'ON gm.user_id= ' || user_id || ' AND gm.group_id=user_group.id';
+
+ tsv = to_tsvector('');
+ FOR onerow in EXECUTE group_query LOOP
+ tsv = tsv || to_tsvector(onerow.group_name);
+ END LOOP;
+
+ user_query = 'SELECT username, about FROM auth_user WHERE id=' || user_id;
+ FOR onerow in EXECUTE user_query LOOP
+ tsv = tsv || to_tsvector(onerow.username) || to_tsvector(onerow.about);
+ END LOOP;
+ RETURN tsv;
+END;
+$$ LANGUAGE plpgsql;
+
+/* create tsvector columns in the content tables */
+SELECT add_tsvector_column('text_search_vector', 'auth_user');
+
+/* populate tsvectors with data */
+UPDATE auth_user SET text_search_vector = get_auth_user_tsv(id);
+
+/* one trigger per table for tsv updates */
+
+/* set up auth_user triggers */
+CREATE OR REPLACE FUNCTION auth_user_tsv_update_handler()
+RETURNS trigger AS
+$$
+BEGIN
+ new.text_search_vector = get_auth_user_tsv(new.id);
+ RETURN new;
+END;
+$$ LANGUAGE plpgsql;
+DROP TRIGGER IF EXISTS auth_user_tsv_update_trigger ON auth_user;
+
+CREATE TRIGGER auth_user_tsv_update_trigger
+BEFORE INSERT OR UPDATE ON auth_user
+FOR EACH ROW EXECUTE PROCEDURE auth_user_tsv_update_handler();
+
+/* group membership trigger - reindex users when group membership
+ * changes */
+CREATE OR REPLACE FUNCTION group_membership_tsv_update_handler()
+RETURNS trigger AS
+$$
+DECLARE
+ tsv tsvector;
+ user_query text;
+BEGIN
+ user_query = 'UPDATE auth_user SET username=username WHERE ' ||
+ 'id=' || new.user_id;
+ /* just trigger the tsv update on user */
+ EXECUTE user_query;
+ RETURN new;
+END;
+$$ LANGUAGE plpgsql;
+
+DROP TRIGGER IF EXISTS group_membership_tsv_update_trigger
+ON auth_user_groups;
+
+CREATE TRIGGER group_membership_tsv_update_trigger
+AFTER INSERT OR DELETE
+ON auth_user_groups
+FOR EACH ROW EXECUTE PROCEDURE group_membership_tsv_update_handler();
+
+/* todo: whenever group name changes - also
+ * reindex users belonging to the group */
+
+DROP INDEX IF EXISTS auth_user_search_idx;
+
+CREATE INDEX auth_user_search_idx ON auth_user
+USING gin(text_search_vector);
diff --git a/askbot/search/state_manager.py b/askbot/search/state_manager.py
index f8154865..a02f1577 100644
--- a/askbot/search/state_manager.py
+++ b/askbot/search/state_manager.py
@@ -117,6 +117,10 @@ class SearchState(object):
else:
self.sort = sort
+ #patch for empty stripped query, relevance sorting is useless then
+ if self.stripped_query in (None, '') and sort == 'relevance-desc':
+ self.sort = const.DEFAULT_POST_SORT_METHOD
+
self.tags = []
if tags:
for t in tags.split(const.TAG_SEP):