456 lines
13 KiB
PL/PgSQL
456 lines
13 KiB
PL/PgSQL
--
|
|
-- Table structure for table `#__finder_filters`
|
|
--
|
|
|
|
CREATE TABLE IF NOT EXISTS "#__finder_filters" (
|
|
"filter_id" serial NOT NULL,
|
|
"title" varchar(255) NOT NULL,
|
|
"alias" varchar(255) NOT NULL,
|
|
"state" smallint DEFAULT 1 NOT NULL,
|
|
"created" timestamp without time zone NOT NULL,
|
|
"created_by" integer DEFAULT 0 NOT NULL,
|
|
"created_by_alias" varchar(255) DEFAULT '' NOT NULL,
|
|
"modified" timestamp without time zone NOT NULL,
|
|
"modified_by" integer DEFAULT 0 NOT NULL,
|
|
"checked_out" integer DEFAULT 0 NOT NULL,
|
|
"checked_out_time" timestamp without time zone,
|
|
"map_count" integer DEFAULT 0 NOT NULL,
|
|
"data" text,
|
|
"params" text,
|
|
PRIMARY KEY ("filter_id")
|
|
);
|
|
|
|
--
|
|
-- Table structure for table `#__finder_links`
|
|
--
|
|
|
|
CREATE TABLE IF NOT EXISTS "#__finder_links" (
|
|
"link_id" serial NOT NULL,
|
|
"url" varchar(255) NOT NULL,
|
|
"route" varchar(255) NOT NULL,
|
|
"title" varchar(400) DEFAULT NULL,
|
|
"description" text,
|
|
"indexdate" timestamp without time zone NOT NULL,
|
|
"md5sum" varchar(32) DEFAULT NULL,
|
|
"published" smallint DEFAULT 1 NOT NULL,
|
|
"state" integer DEFAULT 1 NOT NULL,
|
|
"access" integer DEFAULT 0 NOT NULL,
|
|
"language" varchar(7) DEFAULT '' NOT NULL,
|
|
"publish_start_date" timestamp without time zone,
|
|
"publish_end_date" timestamp without time zone,
|
|
"start_date" timestamp without time zone,
|
|
"end_date" timestamp without time zone,
|
|
"list_price" numeric(8,2) DEFAULT 0 NOT NULL,
|
|
"sale_price" numeric(8,2) DEFAULT 0 NOT NULL,
|
|
"type_id" bigint NOT NULL,
|
|
"object" bytea,
|
|
PRIMARY KEY ("link_id")
|
|
);
|
|
CREATE INDEX "#__finder_links_idx_type" on "#__finder_links" ("type_id");
|
|
CREATE INDEX "#__finder_links_idx_title" on "#__finder_links" ("title");
|
|
CREATE INDEX "#__finder_links_idx_md5" on "#__finder_links" ("md5sum");
|
|
CREATE INDEX "#__finder_links_idx_language" on "#__finder_links" ("language");
|
|
CREATE INDEX "#__finder_links_idx_url" on "#__finder_links" (substr(url,0,76));
|
|
CREATE INDEX "#__finder_links_idx_published_list" on "#__finder_links" ("published", "state", "access", "publish_start_date", "publish_end_date", "list_price");
|
|
CREATE INDEX "#__finder_links_idx_published_sale" on "#__finder_links" ("published", "state", "access", "publish_start_date", "publish_end_date", "sale_price");
|
|
|
|
--
|
|
-- Table structure for table `#__finder_links_terms`
|
|
--
|
|
|
|
CREATE TABLE IF NOT EXISTS "#__finder_links_terms" (
|
|
"link_id" integer NOT NULL,
|
|
"term_id" integer NOT NULL,
|
|
"weight" numeric(8,2) DEFAULT 0 NOT NULL,
|
|
PRIMARY KEY ("link_id", "term_id")
|
|
);
|
|
CREATE INDEX "#__finder_links_terms_idx_term_weight" on "#__finder_links_terms" ("term_id", "weight");
|
|
CREATE INDEX "#__finder_links_terms_idx_link_term_weight" on "#__finder_links_terms" ("link_id", "term_id", "weight");
|
|
|
|
--
|
|
-- Table structure for table `#__finder_logging`
|
|
--
|
|
|
|
CREATE TABLE IF NOT EXISTS "#__finder_logging" (
|
|
"searchterm" character varying(255) NOT NULL DEFAULT '',
|
|
"md5sum" character varying(32) NOT NULL DEFAULT '',
|
|
"query" bytea NOT NULL,
|
|
"hits" integer NOT NULL DEFAULT 1,
|
|
"results" integer NOT NULL DEFAULT 0,
|
|
PRIMARY KEY ("md5sum")
|
|
);
|
|
CREATE INDEX "#__finder_logging_idx_md5sum" on "#__finder_logging" ("md5sum");
|
|
CREATE INDEX "#__finder_logging_idx_searchterm" on "#__finder_logging" ("searchterm");
|
|
|
|
--
|
|
-- Table structure for table `#__finder_taxonomy`
|
|
--
|
|
|
|
CREATE TABLE IF NOT EXISTS "#__finder_taxonomy" (
|
|
"id" serial NOT NULL,
|
|
"parent_id" integer DEFAULT 0 NOT NULL,
|
|
"lft" integer DEFAULT 0 NOT NULL,
|
|
"rgt" integer DEFAULT 0 NOT NULL,
|
|
"level" integer DEFAULT 0 NOT NULL,
|
|
"path" VARCHAR(400) NOT NULL DEFAULT '',
|
|
"title" VARCHAR(255) NOT NULL DEFAULT '',
|
|
"alias" VARCHAR(400) NOT NULL DEFAULT '',
|
|
"state" smallint DEFAULT 1 NOT NULL,
|
|
"access" smallint DEFAULT 1 NOT NULL,
|
|
"language" varchar(7) DEFAULT '' NOT NULL,
|
|
PRIMARY KEY ("id")
|
|
);
|
|
CREATE INDEX "#__finder_taxonomy_state" on "#__finder_taxonomy" ("state");
|
|
CREATE INDEX "#__finder_taxonomy_access" on "#__finder_taxonomy" ("access");
|
|
CREATE INDEX "#__finder_taxonomy_path" on "#__finder_taxonomy" ("path");
|
|
CREATE INDEX "#__finder_taxonomy_lft_rgt" on "#__finder_taxonomy" ("lft", "rgt");
|
|
CREATE INDEX "#__finder_taxonomy_alias" on "#__finder_taxonomy" ("alias");
|
|
CREATE INDEX "#__finder_taxonomy_language" on "#__finder_taxonomy" ("language");
|
|
CREATE INDEX "#__finder_taxonomy_idx_parent_published" on "#__finder_taxonomy" ("parent_id", "state", "access");
|
|
|
|
--
|
|
-- Dumping data for table `#__finder_taxonomy`
|
|
--
|
|
|
|
INSERT INTO "#__finder_taxonomy" ("id", "parent_id", "lft", "rgt", "level", "path", "title", "alias", "state", "access", "language") VALUES
|
|
(1, 0, 0, 1, 0, '', 'ROOT', 'root', 1, 1, '*');
|
|
|
|
SELECT setval('#__finder_taxonomy_id_seq', 2, false);
|
|
|
|
--
|
|
-- Table structure for table `#__finder_taxonomy_map`
|
|
--
|
|
|
|
CREATE TABLE IF NOT EXISTS "#__finder_taxonomy_map" (
|
|
"link_id" integer NOT NULL,
|
|
"node_id" integer NOT NULL,
|
|
PRIMARY KEY ("link_id", "node_id")
|
|
);
|
|
CREATE INDEX "#__finder_taxonomy_map_link_id" on "#__finder_taxonomy_map" ("link_id");
|
|
CREATE INDEX "#__finder_taxonomy_map_node_id" on "#__finder_taxonomy_map" ("node_id");
|
|
|
|
--
|
|
-- Table structure for table `#__finder_terms`
|
|
--
|
|
|
|
CREATE TABLE IF NOT EXISTS "#__finder_terms" (
|
|
"term_id" serial NOT NULL,
|
|
"term" varchar(75) NOT NULL,
|
|
"stem" varchar(75) DEFAULT '' NOT NULL,
|
|
"common" smallint DEFAULT 0 NOT NULL,
|
|
"phrase" smallint DEFAULT 0 NOT NULL,
|
|
"weight" numeric(8,2) DEFAULT 0 NOT NULL,
|
|
"soundex" varchar(75) DEFAULT '' NOT NULL,
|
|
"links" integer DEFAULT 0 NOT NULL,
|
|
"language" varchar(7) DEFAULT '' NOT NULL,
|
|
PRIMARY KEY ("term_id"),
|
|
CONSTRAINT "#__finder_terms_idx_term_language" UNIQUE ("term", "language")
|
|
);
|
|
CREATE INDEX "#__finder_terms_idx_term_phrase" on "#__finder_terms" ("term", "phrase");
|
|
CREATE INDEX "#__finder_terms_idx_stem_phrase" on "#__finder_terms" ("stem", "phrase");
|
|
CREATE INDEX "#__finder_terms_idx_soundex_phrase" on "#__finder_terms" ("soundex", "phrase");
|
|
CREATE INDEX "#__finder_terms_idx_language" on "#__finder_terms" ("language");
|
|
|
|
--
|
|
-- Table structure for table `#__finder_terms_common`
|
|
--
|
|
|
|
CREATE TABLE IF NOT EXISTS "#__finder_terms_common" (
|
|
"term" varchar(75) NOT NULL,
|
|
"language" varchar(7) DEFAULT '' NOT NULL,
|
|
"custom" integer DEFAULT 0 NOT NULL,
|
|
CONSTRAINT "#__finder_terms_common_idx_term_language" UNIQUE ("term", "language")
|
|
);
|
|
CREATE INDEX "#__finder_terms_common_idx_lang" on "#__finder_terms_common" ("language");
|
|
|
|
--
|
|
-- Dumping data for table `#__finder_terms_common`
|
|
--
|
|
|
|
INSERT INTO "#__finder_terms_common" ("term", "language", "custom") VALUES
|
|
('i', 'en', 0),
|
|
('me', 'en', 0),
|
|
('my', 'en', 0),
|
|
('myself', 'en', 0),
|
|
('we', 'en', 0),
|
|
('our', 'en', 0),
|
|
('ours', 'en', 0),
|
|
('ourselves', 'en', 0),
|
|
('you', 'en', 0),
|
|
('your', 'en', 0),
|
|
('yours', 'en', 0),
|
|
('yourself', 'en', 0),
|
|
('yourselves', 'en', 0),
|
|
('he', 'en', 0),
|
|
('him', 'en', 0),
|
|
('his', 'en', 0),
|
|
('himself', 'en', 0),
|
|
('she', 'en', 0),
|
|
('her', 'en', 0),
|
|
('hers', 'en', 0),
|
|
('herself', 'en', 0),
|
|
('it', 'en', 0),
|
|
('its', 'en', 0),
|
|
('itself', 'en', 0),
|
|
('they', 'en', 0),
|
|
('them', 'en', 0),
|
|
('their', 'en', 0),
|
|
('theirs', 'en', 0),
|
|
('themselves', 'en', 0),
|
|
('what', 'en', 0),
|
|
('which', 'en', 0),
|
|
('who', 'en', 0),
|
|
('whom', 'en', 0),
|
|
('this', 'en', 0),
|
|
('that', 'en', 0),
|
|
('these', 'en', 0),
|
|
('those', 'en', 0),
|
|
('am', 'en', 0),
|
|
('is', 'en', 0),
|
|
('are', 'en', 0),
|
|
('was', 'en', 0),
|
|
('were', 'en', 0),
|
|
('be', 'en', 0),
|
|
('been', 'en', 0),
|
|
('being', 'en', 0),
|
|
('have', 'en', 0),
|
|
('has', 'en', 0),
|
|
('had', 'en', 0),
|
|
('having', 'en', 0),
|
|
('do', 'en', 0),
|
|
('does', 'en', 0),
|
|
('did', 'en', 0),
|
|
('doing', 'en', 0),
|
|
('would', 'en', 0),
|
|
('should', 'en', 0),
|
|
('could', 'en', 0),
|
|
('ought', 'en', 0),
|
|
('i''m', 'en', 0),
|
|
('you''re', 'en', 0),
|
|
('he''s', 'en', 0),
|
|
('she''s', 'en', 0),
|
|
('it''s', 'en', 0),
|
|
('we''re', 'en', 0),
|
|
('they''re', 'en', 0),
|
|
('i''ve', 'en', 0),
|
|
('you''ve', 'en', 0),
|
|
('we''ve', 'en', 0),
|
|
('they''ve', 'en', 0),
|
|
('i''d', 'en', 0),
|
|
('you''d', 'en', 0),
|
|
('he''d', 'en', 0),
|
|
('she''d', 'en', 0),
|
|
('we''d', 'en', 0),
|
|
('they''d', 'en', 0),
|
|
('i''ll', 'en', 0),
|
|
('you''ll', 'en', 0),
|
|
('he''ll', 'en', 0),
|
|
('she''ll', 'en', 0),
|
|
('we''ll', 'en', 0),
|
|
('they''ll', 'en', 0),
|
|
('isn''t', 'en', 0),
|
|
('aren''t', 'en', 0),
|
|
('wasn''t', 'en', 0),
|
|
('weren''t', 'en', 0),
|
|
('hasn''t', 'en', 0),
|
|
('haven''t', 'en', 0),
|
|
('hadn''t', 'en', 0),
|
|
('doesn''t', 'en', 0),
|
|
('don''t', 'en', 0),
|
|
('didn''t', 'en', 0),
|
|
('won''t', 'en', 0),
|
|
('wouldn''t', 'en', 0),
|
|
('shan''t', 'en', 0),
|
|
('shouldn''t', 'en', 0),
|
|
('can''t', 'en', 0),
|
|
('cannot', 'en', 0),
|
|
('couldn''t', 'en', 0),
|
|
('mustn''t', 'en', 0),
|
|
('let''s', 'en', 0),
|
|
('that''s', 'en', 0),
|
|
('who''s', 'en', 0),
|
|
('what''s', 'en', 0),
|
|
('here''s', 'en', 0),
|
|
('there''s', 'en', 0),
|
|
('when''s', 'en', 0),
|
|
('where''s', 'en', 0),
|
|
('why''s', 'en', 0),
|
|
('how''s', 'en', 0),
|
|
('a', 'en', 0),
|
|
('an', 'en', 0),
|
|
('the', 'en', 0),
|
|
('and', 'en', 0),
|
|
('but', 'en', 0),
|
|
('if', 'en', 0),
|
|
('or', 'en', 0),
|
|
('because', 'en', 0),
|
|
('as', 'en', 0),
|
|
('until', 'en', 0),
|
|
('while', 'en', 0),
|
|
('of', 'en', 0),
|
|
('at', 'en', 0),
|
|
('by', 'en', 0),
|
|
('for', 'en', 0),
|
|
('with', 'en', 0),
|
|
('about', 'en', 0),
|
|
('against', 'en', 0),
|
|
('between', 'en', 0),
|
|
('into', 'en', 0),
|
|
('through', 'en', 0),
|
|
('during', 'en', 0),
|
|
('before', 'en', 0),
|
|
('after', 'en', 0),
|
|
('above', 'en', 0),
|
|
('below', 'en', 0),
|
|
('to', 'en', 0),
|
|
('from', 'en', 0),
|
|
('up', 'en', 0),
|
|
('down', 'en', 0),
|
|
('in', 'en', 0),
|
|
('out', 'en', 0),
|
|
('on', 'en', 0),
|
|
('off', 'en', 0),
|
|
('over', 'en', 0),
|
|
('under', 'en', 0),
|
|
('again', 'en', 0),
|
|
('further', 'en', 0),
|
|
('then', 'en', 0),
|
|
('once', 'en', 0),
|
|
('here', 'en', 0),
|
|
('there', 'en', 0),
|
|
('when', 'en', 0),
|
|
('where', 'en', 0),
|
|
('why', 'en', 0),
|
|
('how', 'en', 0),
|
|
('all', 'en', 0),
|
|
('any', 'en', 0),
|
|
('both', 'en', 0),
|
|
('each', 'en', 0),
|
|
('few', 'en', 0),
|
|
('more', 'en', 0),
|
|
('most', 'en', 0),
|
|
('other', 'en', 0),
|
|
('some', 'en', 0),
|
|
('such', 'en', 0),
|
|
('no', 'en', 0),
|
|
('nor', 'en', 0),
|
|
('not', 'en', 0),
|
|
('only', 'en', 0),
|
|
('own', 'en', 0),
|
|
('same', 'en', 0),
|
|
('so', 'en', 0),
|
|
('than', 'en', 0),
|
|
('too', 'en', 0),
|
|
('very', 'en', 0);
|
|
|
|
--
|
|
-- Table structure for table `#__finder_tokens`
|
|
--
|
|
|
|
CREATE TABLE IF NOT EXISTS "#__finder_tokens" (
|
|
"term" varchar(75) NOT NULL,
|
|
"stem" varchar(75) DEFAULT '' NOT NULL,
|
|
"common" smallint DEFAULT 0 NOT NULL,
|
|
"phrase" smallint DEFAULT 0 NOT NULL,
|
|
"weight" numeric(8,2) DEFAULT 1 NOT NULL,
|
|
"context" smallint DEFAULT 2 NOT NULL,
|
|
"language" varchar(7) DEFAULT '' NOT NULL
|
|
);
|
|
CREATE INDEX "#__finder_tokens_idx_word" on "#__finder_tokens" ("term");
|
|
CREATE INDEX "#__finder_tokens_idx_stem" on "#__finder_tokens" ("stem");
|
|
CREATE INDEX "#__finder_tokens_idx_context" on "#__finder_tokens" ("context");
|
|
CREATE INDEX "#__finder_tokens_idx_language" on "#__finder_tokens" ("language");
|
|
|
|
--
|
|
-- Table structure for table `#__finder_tokens_aggregate`
|
|
--
|
|
|
|
CREATE TABLE IF NOT EXISTS "#__finder_tokens_aggregate" (
|
|
"term_id" integer NOT NULL,
|
|
"term" varchar(75) NOT NULL,
|
|
"stem" varchar(75) DEFAULT '' NOT NULL,
|
|
"common" smallint DEFAULT 0 NOT NULL,
|
|
"phrase" smallint DEFAULT 0 NOT NULL,
|
|
"term_weight" numeric(8,2) NOT NULL DEFAULT 0,
|
|
"context" smallint DEFAULT 2 NOT NULL,
|
|
"context_weight" numeric(8,2) NOT NULL DEFAULT 0,
|
|
"total_weight" numeric(8,2) NOT NULL DEFAULT 0,
|
|
"language" varchar(7) DEFAULT '' NOT NULL
|
|
);
|
|
CREATE INDEX "#__finder_tokens_aggregate_token" on "#__finder_tokens_aggregate" ("term");
|
|
CREATE INDEX "_#__finder_tokens_aggregate_keyword_id" on "#__finder_tokens_aggregate" ("term_id");
|
|
|
|
--
|
|
-- Table structure for table `#__finder_types`
|
|
--
|
|
|
|
CREATE TABLE IF NOT EXISTS "#__finder_types" (
|
|
"id" serial NOT NULL,
|
|
"title" varchar(100) NOT NULL,
|
|
"mime" varchar(100) DEFAULT '' NOT NULL,
|
|
PRIMARY KEY ("id"),
|
|
CONSTRAINT "#__finder_types_title" UNIQUE ("title")
|
|
);
|
|
|
|
--
|
|
-- Here is SOUNDEX replacement for those who can't enable fuzzystrmatch module
|
|
-- from contrib folder.
|
|
-- This function comes from https://wiki.postgresql.org/wiki/Soundex
|
|
-- and is distributed with GPL license.
|
|
-- Thanks to its author, Marti Raudsepp, that published this piece of code.
|
|
--
|
|
|
|
CREATE OR REPLACE FUNCTION soundex(input text) RETURNS text
|
|
IMMUTABLE STRICT COST 500 LANGUAGE plpgsql
|
|
AS $$
|
|
DECLARE
|
|
soundex text = '';
|
|
char text;
|
|
symbol text;
|
|
last_symbol text = '';
|
|
pos int = 1;
|
|
BEGIN
|
|
WHILE length(soundex) < 4 LOOP
|
|
char = upper(substr(input, pos, 1));
|
|
pos = pos + 1;
|
|
CASE char
|
|
WHEN '' THEN
|
|
-- End of input string
|
|
IF soundex = '' THEN
|
|
RETURN '';
|
|
ELSE
|
|
RETURN rpad(soundex, 4, '0');
|
|
END IF;
|
|
WHEN 'B', 'F', 'P', 'V' THEN
|
|
symbol = '1';
|
|
WHEN 'C', 'G', 'J', 'K', 'Q', 'S', 'X', 'Z' THEN
|
|
symbol = '2';
|
|
WHEN 'D', 'T' THEN
|
|
symbol = '3';
|
|
WHEN 'L' THEN
|
|
symbol = '4';
|
|
WHEN 'M', 'N' THEN
|
|
symbol = '5';
|
|
WHEN 'R' THEN
|
|
symbol = '6';
|
|
ELSE
|
|
-- Not a consonant; no output, but next similar consonant will be re-recorded
|
|
symbol = '';
|
|
END CASE;
|
|
|
|
IF soundex = '' THEN
|
|
-- First character; only accept strictly English ASCII characters
|
|
IF char ~>=~ 'A' AND char ~<=~ 'Z' THEN
|
|
soundex = char;
|
|
last_symbol = symbol;
|
|
END IF;
|
|
ELSIF last_symbol != symbol THEN
|
|
soundex = soundex || symbol;
|
|
last_symbol = symbol;
|
|
END IF;
|
|
END LOOP;
|
|
|
|
RETURN soundex;
|
|
END;
|
|
$$;
|