CREATE COLUMN TABLE employee
(
id INTEGER PRIMARY KEY,
firstname SHORTTEXT(100) FUZZY SEARCH INDEX ON,
lastname SHORTTEXT(100) FUZZY SEARCH INDEX ON,
address NVARCHAR(100) FUZZY SEARCH INDEX ON,
postcode NVARCHAR(20) ,
cityname NVARCHAR(100) ,
countrycode NVARCHAR(2),
);
INSERT INTO employee VALUES(1, 'Michael', 'Milliken', '3999 WEST CHESTER PIKE', '001', 'NEWTON SQUARE', 'PA');
CREATE COLUMN TABLE stopwords
(
stopword_id VARCHAR(32) PRIMARY KEY,
list_id VARCHAR(32) NOT NULL,
language_code CHAR(2) NOT NULL,
term NVARCHAR(200) NOT NULL
);
-- to be able to use stopwords, a stopword table is needed:
CREATE COLUMN TABLE stopwords
(
stopword_id VARCHAR(32) PRIMARY KEY,
list_id VARCHAR(32) NOT NULL,
language_code VARCHAR(2),
term NVARCHAR(200) NOT NULL
);
INSERT INTO stopwords VALUES('1', 'firstname', 'en', 'Dr');
INSERT INTO stopwords VALUES('2', 'firstname', 'en', 'Mr');
INSERT INTO stopwords VALUES('3', 'firstname', 'en', 'Mrs');
INSERT INTO stopwords VALUES('4', 'firstname', 'en', 'Sir');
INSERT INTO stopwords VALUES('5', 'firstname', 'en', 'Prof');
CREATE COLUMN TABLE termmappings
(
mapping_id VARCHAR(32) PRIMARY KEY,
list_id VARCHAR(32) NOT NULL,
language_code VARCHAR(2),
term_1 NVARCHAR(200) NOT NULL,
term_2 NVARCHAR(200) NOT NULL,
weight DECIMAL NOT NULL
);
-- and for term mappings another table:
CREATE COLUMN TABLE termmappings
(
mapping_id VARCHAR(32) PRIMARY KEY,
list_id VARCHAR(32) NOT NULL,
language_code VARCHAR(2),
term_1 NVARCHAR(255) NOT NULL,
term_2 NVARCHAR(255) NOT NULL,
weight DECIMAL NOT NULL
);
INSERT INTO termmappings VALUES('1', 'firstname', 'en', 'Michael', 'Mike', '0.9');
INSERT INTO termmappings VALUES('2', 'firstname', 'en', 'Mike', 'Michael', '0.9');
INSERT INTO termmappings VALUES('3', 'firstname', 'en', 'Michael', 'Miky', '0.8');
INSERT INTO termmappings VALUES('4', 'firstname', 'en', 'Miky', 'Michael', '0.8');
INSERT INTO termmappings VALUES('5', 'lastname', 'en', 'Milly', 'Milliken', '0.9');
INSERT INTO termmappings VALUES('6', 'lastname', 'en', 'Mille', 'Milliken', '0.9');
CALL SYS.EXECUTE_SEARCH_RULE_SET('
<query>
<ruleset name="ZSearch_RuleProject:Search_Rule.searchruleset" />
<column name="FIRSTNAME">Prof. Mike</column>
<column name="LASTNAME">Milly</column>
<resultsetcolumn name="_SCORE" />
<resultsetcolumn name="_RULE_ID" />
<resultsetcolumn name="_RULE_NUMBER" />
<resultsetcolumn name="FIRSTNAME" />
<resultsetcolumn name="LASTNAME" />
</query>
');
CREATE COLUMN TABLE RESULT_STORE (
_SCORE FLOAT,
_RULE_ID VARCHAR(255),
"FIRSTNAME" TEXT,
"LASTNAME" TEXT,
"ADDRESS" NVARCHAR(100),
"POSTCODE" NVARCHAR(20),
"CITYNAME" NVARCHAR(100),
"COUNTRYCODE" NVARCHAR(2)
);
CALL SYS.EXECUTE_SEARCH_RULE_SET('
<query>
<ruleset name="ZSearch_RuleProject:Search_Rule.searchruleset" />
<resulttablename name="RESULT_STORE"/>
<column name="FIRSTNAME">Prof. Mike</column>
<column name="LASTNAME">Milly</column>
</query>
');
Select * from RESULT_STORE;
CALL SYS.EXECUTE_SEARCH_RULE_SET('
<query>
<ruleset scoreSelection="firstRule">
<attributeView name="TRAINING::ZAT_SEARCH_RULESET">
<keyColumn name="ID"/>
</attributeView>
<termMappingsTableBased schema="SYSTEM" table="TERMMAPPINGS">
<column name="FIRSTNAME">
<list id="FIRSTNAME"/>
</column>
<column name="LASTNAME">
<list id="LASTNAME"/>
</column>
</termMappingsTableBased>
<rule name="Rule 1">
<column minFuzziness="0.8" name="FIRSTNAME">
<ifMissing action="skipColumn"/>
</column>
<column minFuzziness="0.8" name="LASTNAME">
<ifMissing action="skipColumn"/>
</column>
</rule>
</ruleset>
<column name="FIRSTNAME">Mike</column>
<column name="LASTNAME">Milly</column>
<resultsetcolumn name="_SCORE" />
<resultsetcolumn name="_RULE_ID" />
<resultsetcolumn name="_RULE_NUMBER" />
<resultsetcolumn name="FIRSTNAME" />
<resultsetcolumn name="LASTNAME" />
</query>
');
You must be a registered user to add a comment. If you've already registered, sign in. Otherwise, register and sign in.
User | Count |
---|---|
26 | |
24 | |
21 | |
13 | |
9 | |
9 | |
9 | |
9 | |
8 | |
8 |