Skip to content

Instantly share code, notes, and snippets.

@arialdomartini
Created May 29, 2013 14:30
Show Gist options
  • Save arialdomartini/5670697 to your computer and use it in GitHub Desktop.
Save arialdomartini/5670697 to your computer and use it in GitHub Desktop.
DDL per relatedwords e containingwords
CREATE TABLE qrtz_job_details
(
SCHED_NAME VARCHAR(120) NOT NULL,
JOB_NAME VARCHAR(200) NOT NULL,
JOB_GROUP VARCHAR(200) NOT NULL,
DESCRIPTION VARCHAR(250) NULL,
JOB_CLASS_NAME VARCHAR(250) NOT NULL,
IS_DURABLE BOOL NOT NULL,
IS_NONCONCURRENT BOOL NOT NULL,
IS_UPDATE_DATA BOOL NOT NULL,
REQUESTS_RECOVERY BOOL NOT NULL,
JOB_DATA BYTEA NULL,
PRIMARY KEY (SCHED_NAME,JOB_NAME,JOB_GROUP)
);
CREATE TABLE qrtz_triggers
(
SCHED_NAME VARCHAR(120) NOT NULL,
TRIGGER_NAME VARCHAR(200) NOT NULL,
TRIGGER_GROUP VARCHAR(200) NOT NULL,
JOB_NAME VARCHAR(200) NOT NULL,
JOB_GROUP VARCHAR(200) NOT NULL,
DESCRIPTION VARCHAR(250) NULL,
NEXT_FIRE_TIME BIGINT NULL,
PREV_FIRE_TIME BIGINT NULL,
PRIORITY INTEGER NULL,
TRIGGER_STATE VARCHAR(16) NOT NULL,
TRIGGER_TYPE VARCHAR(8) NOT NULL,
START_TIME BIGINT NOT NULL,
END_TIME BIGINT NULL,
CALENDAR_NAME VARCHAR(200) NULL,
MISFIRE_INSTR SMALLINT NULL,
JOB_DATA BYTEA NULL,
PRIMARY KEY (SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP),
FOREIGN KEY (SCHED_NAME,JOB_NAME,JOB_GROUP)
REFERENCES QRTZ_JOB_DETAILS(SCHED_NAME,JOB_NAME,JOB_GROUP)
);
CREATE TABLE qrtz_simple_triggers
(
SCHED_NAME VARCHAR(120) NOT NULL,
TRIGGER_NAME VARCHAR(200) NOT NULL,
TRIGGER_GROUP VARCHAR(200) NOT NULL,
REPEAT_COUNT BIGINT NOT NULL,
REPEAT_INTERVAL BIGINT NOT NULL,
TIMES_TRIGGERED BIGINT NOT NULL,
PRIMARY KEY (SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP),
FOREIGN KEY (SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP)
REFERENCES QRTZ_TRIGGERS(SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP)
);
CREATE TABLE qrtz_cron_triggers
(
SCHED_NAME VARCHAR(120) NOT NULL,
TRIGGER_NAME VARCHAR(200) NOT NULL,
TRIGGER_GROUP VARCHAR(200) NOT NULL,
CRON_EXPRESSION VARCHAR(120) NOT NULL,
TIME_ZONE_ID VARCHAR(80),
PRIMARY KEY (SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP),
FOREIGN KEY (SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP)
REFERENCES QRTZ_TRIGGERS(SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP)
);
CREATE TABLE qrtz_simprop_triggers
(
SCHED_NAME VARCHAR(120) NOT NULL,
TRIGGER_NAME VARCHAR(200) NOT NULL,
TRIGGER_GROUP VARCHAR(200) NOT NULL,
STR_PROP_1 VARCHAR(512) NULL,
STR_PROP_2 VARCHAR(512) NULL,
STR_PROP_3 VARCHAR(512) NULL,
INT_PROP_1 INT NULL,
INT_PROP_2 INT NULL,
LONG_PROP_1 BIGINT NULL,
LONG_PROP_2 BIGINT NULL,
DEC_PROP_1 NUMERIC(13,4) NULL,
DEC_PROP_2 NUMERIC(13,4) NULL,
BOOL_PROP_1 BOOL NULL,
BOOL_PROP_2 BOOL NULL,
PRIMARY KEY (SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP),
FOREIGN KEY (SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP)
REFERENCES QRTZ_TRIGGERS(SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP)
);
CREATE TABLE qrtz_blob_triggers
(
SCHED_NAME VARCHAR(120) NOT NULL,
TRIGGER_NAME VARCHAR(200) NOT NULL,
TRIGGER_GROUP VARCHAR(200) NOT NULL,
BLOB_DATA BYTEA NULL,
PRIMARY KEY (SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP),
FOREIGN KEY (SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP)
REFERENCES QRTZ_TRIGGERS(SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP)
);
CREATE TABLE qrtz_calendars
(
SCHED_NAME VARCHAR(120) NOT NULL,
CALENDAR_NAME VARCHAR(200) NOT NULL,
CALENDAR BYTEA NOT NULL,
PRIMARY KEY (SCHED_NAME,CALENDAR_NAME)
);
CREATE TABLE qrtz_paused_trigger_grps
(
SCHED_NAME VARCHAR(120) NOT NULL,
TRIGGER_GROUP VARCHAR(200) NOT NULL,
PRIMARY KEY (SCHED_NAME,TRIGGER_GROUP)
);
CREATE TABLE qrtz_fired_triggers
(
SCHED_NAME VARCHAR(120) NOT NULL,
ENTRY_ID VARCHAR(95) NOT NULL,
TRIGGER_NAME VARCHAR(200) NOT NULL,
TRIGGER_GROUP VARCHAR(200) NOT NULL,
INSTANCE_NAME VARCHAR(200) NOT NULL,
FIRED_TIME BIGINT NOT NULL,
PRIORITY INTEGER NOT NULL,
STATE VARCHAR(16) NOT NULL,
JOB_NAME VARCHAR(200) NULL,
JOB_GROUP VARCHAR(200) NULL,
IS_NONCONCURRENT BOOL NULL,
REQUESTS_RECOVERY BOOL NULL,
PRIMARY KEY (SCHED_NAME,ENTRY_ID)
);
CREATE TABLE qrtz_scheduler_state
(
SCHED_NAME VARCHAR(120) NOT NULL,
INSTANCE_NAME VARCHAR(200) NOT NULL,
LAST_CHECKIN_TIME BIGINT NOT NULL,
CHECKIN_INTERVAL BIGINT NOT NULL,
PRIMARY KEY (SCHED_NAME,INSTANCE_NAME)
);
CREATE TABLE qrtz_locks
(
SCHED_NAME VARCHAR(120) NOT NULL,
LOCK_NAME VARCHAR(40) NOT NULL,
PRIMARY KEY (SCHED_NAME,LOCK_NAME)
);
CREATE TABLE "jobseeker_statement_pivot" (
"email" varchar(50),
"userid" varchar(50),
"shortid" varchar(50),
"lastdirectjobmailsentdatetime" timestamp,
"what" varchar(4096),
"where" varchar(4096),
"tsv" tsvector
)WITH (OIDS=FALSE);
CREATE TRIGGER "tr_jobseeker_statement_pivot_beforeinsertupdate" BEFORE INSERT OR UPDATE ON "public"."jobseeker_statement_pivot"
FOR EACH ROW
EXECUTE PROCEDURE "tsvector_update_trigger"('tsv', 'pg_catalog.english', 'what');
CREATE OR REPLACE FUNCTION "public"."js_campaign_materialize_pivot"()
RETURNS "pg_catalog"."void" AS $BODY$BEGIN
SET standard_conforming_strings = on;
IF EXISTS (SELECT relname FROM pg_class where relname='jobseeker_statement_pivot') THEN
TRUNCATE TABLE "jobseeker_statement_pivot";
END IF;
INSERT INTO "jobseeker_statement_pivot"
SELECT
stat."email",
stat."userid",
stat."shortid",
stat."lastdirectjobmailsentdatetime" ,
CASE
WHEN (
REPLACE(split_part(stat.st, '|' :: TEXT, 1),'"','') = '' :: TEXT
) THEN 'nokeyword' :: TEXT
ELSE
lower(REPLACE(trim(split_part(stat.st, '|' :: TEXT, 1)),'"',''))
END AS what,
CASE
WHEN (
REPLACE(trim(split_part(stat.st, '|' :: TEXT, 2)),'"','') = '' :: TEXT
) THEN 'nolocation' :: TEXT
ELSE
lower(REPLACE(trim(split_part(stat.st, '|' :: TEXT, 2)),'"',''))
END AS "where"
FROM (
SELECT "email", "userid","shortid", "lastdirectjobmailsentdatetime" ,
unnest(
string_to_array(
regexp_replace("statementsstring",'([^|]*\|[^|]*\|[^,]*),', '\1~^~', 'g'), '~^~')) AS st
FROM "jobseeker"
where "isjobseeker"= true
) stat;
END;
$BODY$
LANGUAGE 'plpgsql' VOLATILE COST 100
;
CREATE TYPE js_campaign_search_jobseeker_result AS (
"Email" varchar(50),
"UserId" varchar(50),
"ShortId" varchar(50),
"LastDirectJobMailSentDateTime" timestamp
);
CREATE OR REPLACE FUNCTION "public"."js_campaign_search_jobseeker"(loc_lang text, keyw text, not_keyw text, loc text, not_loc text, limit_query text)
RETURNS SETOF "public"."js_campaign_search_jobseeker_result" AS $BODY$
DECLARE
resultsRow js_campaign_search_jobseeker_result%rowtype;
query_search text;
query_search_key text;
query_search_loc text;
lingua regconfig;
BEGIN
query_search_key := '';
IF keyw <> '' OR keyw = NULL THEN
query_search_key := '(' || keyw || ')';
END IF;
IF not_keyw <> '' OR not_keyw = NULL THEN
IF query_search_key <> '' THEN
query_search_key := query_search_key || ' & !(' ||not_keyw || ')' ;
ELSE
query_search_key := '!(' ||not_keyw || ')';
END IF;
END IF;
lingua = loc_lang::regconfig;
RETURN QUERY EXECUTE 'Select "userid","shortid","email","lastdirectjobmailsentdatetime" from "jobseeker_statement_pivot"
where "tsv" @@ to_tsquery('''|| lingua ||''','''|| query_search_key ||''') AND
(
TRIM('''|| loc ||''') = '''' OR EXISTS (
SELECT 1 FROM (
SELECT TRIM(
UNNEST (
string_to_array('''|| loc ||''',''|'')
)
) AS lt
) AS parole_in
where
"jobseeker_statement_pivot"."where" = lower(parole_in.lt)
)
)
AND ( TRIM('''|| not_loc ||''') = '''' OR
NOT EXISTS (
SELECT 1 FROM (
SELECT TRIM(
UNNEST (
string_to_array('''|| not_loc ||''',''|'')
)
) AS lt
) AS parole_out
where
"jobseeker_statement_pivot"."where" = lower(parole_out.lt)
)
)
GROUP BY "userid","shortid","email","lastdirectjobmailsentdatetime"
ORDER BY lastdirectjobmailsentdatetime ASC NULLS FIRST
LIMIT ' || limit_query || ' ;';
END
$BODY$
LANGUAGE 'plpgsql' VOLATILE COST 100;
CREATE OR REPLACE FUNCTION js_campaign_search_jobseeker_count(loc_lang text, keyw text, not_keyw text, loc text, not_loc text)
RETURNS SETOF BIGINT AS $$
DECLARE
quanti integer;
query_search text;
query_search_key text;
query_search_loc text;
lingua regconfig;
BEGIN
query_search_key := '';
IF keyw <> '' OR keyw = NULL THEN
query_search_key := '(' || keyw || ')';
END IF;
IF not_keyw <> '' OR not_keyw = NULL THEN
IF query_search_key <> '' THEN
query_search_key := query_search_key || ' & !(' ||not_keyw || ')' ;
ELSE
query_search_key := '!(' ||not_keyw || ')';
END IF;
END IF;
lingua = loc_lang::regconfig;
RETURN QUERY EXECUTE 'SELECT COUNT(DISTINCT("userid","shortid","email","lastdirectjobmailsentdatetime")) from "jobseeker_statement_pivot"
where "tsv" @@ to_tsquery('''|| lingua ||''','''|| query_search_key ||''') AND
(
TRIM('''|| loc ||''') = '''' OR EXISTS (
SELECT 1 FROM (
SELECT TRIM(
UNNEST (
string_to_array('''|| loc ||''',''|'')
)
) AS lt
) AS parole_in
where
"jobseeker_statement_pivot"."where" = lower(parole_in.lt)
)
)
AND ( TRIM('''|| not_loc ||''') = '''' OR
NOT EXISTS (
SELECT 1 FROM (
SELECT TRIM(
UNNEST (
string_to_array('''|| not_loc ||''',''|'')
)
) AS lt
) AS parole_out
where
"jobseeker_statement_pivot"."where" = lower(parole_out.lt)
)
)';
RETURN;
END
$$ language 'plpgsql';
CREATE INDEX ix_jobseeker_statement_pivot_what ON "jobseeker_statement_pivot" USING gin("tsv");
CREATE INDEX ix_jobseeker_statement_pivot_where ON "jobseeker_statement_pivot" USING hash("where");
CREATE INDEX ix_jobseeker_statement_pivot_useridshortidemaillastdjmsdt ON "jobseeker_statement_pivot" USING btree ("userid", "shortid", "email","lastdirectjobmailsentdatetime");
create index idx_qrtz_j_req_recovery on qrtz_job_details(SCHED_NAME,REQUESTS_RECOVERY);
create index idx_qrtz_j_grp on qrtz_job_details(SCHED_NAME,JOB_GROUP);
create index idx_qrtz_t_j on qrtz_triggers(SCHED_NAME,JOB_NAME,JOB_GROUP);
create index idx_qrtz_t_jg on qrtz_triggers(SCHED_NAME,JOB_GROUP);
create index idx_qrtz_t_c on qrtz_triggers(SCHED_NAME,CALENDAR_NAME);
create index idx_qrtz_t_g on qrtz_triggers(SCHED_NAME,TRIGGER_GROUP);
create index idx_qrtz_t_state on qrtz_triggers(SCHED_NAME,TRIGGER_STATE);
create index idx_qrtz_t_n_state on qrtz_triggers(SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP,TRIGGER_STATE);
create index idx_qrtz_t_n_g_state on qrtz_triggers(SCHED_NAME,TRIGGER_GROUP,TRIGGER_STATE);
create index idx_qrtz_t_next_fire_time on qrtz_triggers(SCHED_NAME,NEXT_FIRE_TIME);
create index idx_qrtz_t_nft_st on qrtz_triggers(SCHED_NAME,TRIGGER_STATE,NEXT_FIRE_TIME);
create index idx_qrtz_t_nft_misfire on qrtz_triggers(SCHED_NAME,MISFIRE_INSTR,NEXT_FIRE_TIME);
create index idx_qrtz_t_nft_st_misfire on qrtz_triggers(SCHED_NAME,MISFIRE_INSTR,NEXT_FIRE_TIME,TRIGGER_STATE);
create index idx_qrtz_t_nft_st_misfire_grp on qrtz_triggers(SCHED_NAME,MISFIRE_INSTR,NEXT_FIRE_TIME,TRIGGER_GROUP,TRIGGER_STATE);
create index idx_qrtz_ft_trig_inst_name on qrtz_fired_triggers(SCHED_NAME,INSTANCE_NAME);
create index idx_qrtz_ft_inst_job_req_rcvry on qrtz_fired_triggers(SCHED_NAME,INSTANCE_NAME,REQUESTS_RECOVERY);
create index idx_qrtz_ft_j_g on qrtz_fired_triggers(SCHED_NAME,JOB_NAME,JOB_GROUP);
create index idx_qrtz_ft_jg on qrtz_fired_triggers(SCHED_NAME,JOB_GROUP);
create index idx_qrtz_ft_t_g on qrtz_fired_triggers(SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP);
create index idx_qrtz_ft_tg on qrtz_fired_triggers(SCHED_NAME,TRIGGER_GROUP);
insert into DatabaseSchemaUpdateTimestamps (LastSchemaUpdateTimestamp, SchemaVersion) values (CURRENT_TIMESTAMP, 19);
-- Table: containingwords
-- DROP TABLE containingwords;
CREATE TABLE containingwords
(
id bigint NOT NULL,
singleword character varying(400),
words character varying(10000),
CONSTRAINT containingwords_pkey PRIMARY KEY (id)
)
WITH (
OIDS=FALSE
);
ALTER TABLE containingwords OWNER TO postgres;
-- Index: byscorejoinedphrases_phrase
-- DROP INDEX byscorejoinedphrases_phrase;
CREATE INDEX byscorejoinedphrases_phrase
ON containingwords
USING btree
(singleword);
----------------------------------------------
-- Table: relatedwords
-- DROP TABLE relatedwords;
CREATE TABLE relatedwords
(
id bigint NOT NULL,
singleword character varying(400),
words character varying(10000),
CONSTRAINT relatedwords_pkey PRIMARY KEY (id)
)
WITH (
OIDS=FALSE
);
ALTER TABLE relatedwords OWNER TO postgres;
-- Index: relatedwords_phrase
-- DROP INDEX relatedwords_phrase;
CREATE INDEX relatedwords_phrase
ON relatedwords
USING btree
(singleword);
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment