User Documentation
 All Files Functions Groups
crf_data_loader.sql_in
Go to the documentation of this file.
1 /* ----------------------------------------------------------------------- *//**
2  *
3  * @file crf_data_loader.sql_in
4  *
5  * @brief Create database tables and import POS/NER training/testing data to the database
6  * @date Feb. 2012
7  *
8  *//* ----------------------------------------------------------------------- */
9 
10 m4_include(`SQLCommon.m4')
11 
12 /**
13 
14 @input
15 
16 -# Prepare an input train data segment table, e.g.:
17 - CREATE TABLE train_segmenttbl (start_pos integer,doc_id integer,seg_text text, max_pos integer)
18 \verbatim
19 sql> select * from train_segmenttbl order by doc_id, start_pos;
20 start_pos | doc_id | seg_text | max_pos
21 ----------+---------+--------------+-------------
22  0 | 1 | madlib | 9
23  1 | 1 | is | 9
24  2 | 1 | an | 9
25  3 | 1 | open-source | 9
26  4 | 1 | library | 9
27  5 | 1 | for | 9
28  6 | 1 | scalable | 9
29  7 | 1 | in-database | 9
30  8 | 1 | analytics | 9
31  9 | 1 | . | 9
32  0 | 2 | it | 16
33  1 | 2 | provides | 16
34  2 | 2 |data-parallel | 16
35  3 | 2 |implementations| 16
36  ...
37  14 | 2 | unstructured | 16
38  15 | 2 | data | 16
39  16 | 2 | . | 16
40 \endverbatim
41 
42 -# Prepare an input dictionary table, e.g.,:
43 - CREATE TABLE crf_dictionary (token text,token_id integer,label text,count integer,total integer)
44 \verbatim
45 sql> select * from crf_dictionary;
46 token | label | count | total
47 ------------+--------+--------------
48  freefall | 11 | 1 | 1
49  policy | 11 | 2 | 2
50  measures | 12 | 1 | 1
51  commitment | 11 | 1 | 1
52  new | 6 | 1 | 1
53  speech | 11 | 1 | 1
54  's | 16 | 2 | 2
55  reckon | 30 | 1 | 1
56  underlying | 28 | 1 | 1
57  ...
58 \endverbatim
59 
60 -# Prepare an input label table, e.g.,:
61 - CREATE TABLE labeltbl (id integer,label character varying)
62 \verbatim
63 sql> select * from labeltbl order by id;
64 id | label
65 ------------+--------
66  0 | CC
67  1 | CD
68  2 | DT
69  3 | EX
70  4 | FW
71  5 | IN
72  6 | JJ
73 ...
74  42 | ,
75  43 | .
76  44 | :
77 \endverbatim
78 
79 -# Prepare an input regex table, e.g.,:
80 - CREATE TABLE crf_regex (pattern text,name text)
81 \verbatim
82 sql> select * from crf_regex;
83 pattern | name
84 ------------- +---------------
85 ^[A-Z][a-z]+$ | InitCapital%
86  ^[A-Z]+$ | isAllCapital%
87  ^.*[0-9]+.*$ | containsDigit%
88  ^.+[.]$ | endsWithDot%
89  ^.+[,]$ | endsWithComma%
90  ^.+er$ | endsWithER%
91  ^.+est$ | endsWithEst%
92  ^.+ed$ | endsWithED%
93 ...
94 \endverbatim
95 
96 -# Prepare an input feature table, e.g.,:
97 - CREATE TABLE featuretbl (id integer,name text,prev_label_id integer,label_id integer,weight float)
98 \verbatim
99 sql> select * from featuretbl order by id;
100 id | name | prev_label_id | label_id | weight
101 -------------------------------------------------------
102 1 | W_chancellor | -1 | 13 | 2.2322
103 2 | E.13 | 13 | 5 | 2.3995
104 3 | U | -1 | 5 | 1.2164
105 4 | W_of | -1 | 5 | 2.8744
106 5 | E.5 | 5 | 2 | 3.7716
107 6 | W_the | -1 | 2 | 4.1790
108 7 | E.2 | 2 | 13 | 0.8957
109 ...
110 \endverbatim
111 
112 -# Prepare an crf feature set table, e.g.,:
113 - CREATE TABLE MADLIB_SCHEMA.crf_feature_dic(f_index integer, f_name text, feature integer[])
114 \verbatim
115 sql> select * from crf_feature_dic order by id;
116 f_index| f_name | feature
117 --------------------------------
118 0 | W_chancellor | -1
119 1 | E.13 | 13
120 2 | U | -1
121 3 | W_of | -1
122 4 | E.5 | 5
123 5 | W_the | -1
124 ...
125 \endverbatim
126 
127 
128 @usage
129 - create tables and import data to the database
130  SELECT madlib.crf_train_data('/path/to/modeldata')
131 
132 */
133 CREATE OR REPLACE FUNCTION MADLIB_SCHEMA.crf_train_data(datapath text) RETURNS void AS
134 $$
135  # import label data to the database
136  query = "DROP TABLE IF EXISTS MADLIB_SCHEMA.crf_label CASCADE;" + \
137  "CREATE TABLE MADLIB_SCHEMA.crf_label(id integer,label text);" + \
138  "COPY MADLIB_SCHEMA.crf_label(id,label) FROM '" + datapath + "/crf_label.tab'";
139  plpy.execute(query);
140 
141  # import regex to regex table
142  query = "DROP TABLE IF EXISTS MADLIB_SCHEMA.crf_regex CASCADE;" + \
143  "CREATE TABLE MADLIB_SCHEMA.crf_regex (pattern text,name text);" + \
144  "COPY MADLIB_SCHEMA.crf_regex(pattern,name) FROM '" + datapath + "/crf_regex.tab'";
145  plpy.execute(query);
146 
147  # import training data to the database
148  query = "DROP TABLE IF EXISTS MADLIB_SCHEMA.train_segmenttbl CASCADE;" + \
149  "CREATE TABLE MADLIB_SCHEMA.train_segmenttbl(start_pos integer,doc_id integer,seg_text text,label integer,max_pos integer);" + \
150  "COPY MADLIB_SCHEMA.train_segmenttbl(start_pos,doc_id,seg_text,label,max_pos) FROM '" + datapath + "/crf_traindata.tab'";
151  plpy.execute(query);
152 
153  query ="DROP TABLE IF EXISTS MADLIB_SCHEMA.crf_feature;" + \
154  "CREATE TABLE MADLIB_SCHEMA.crf_feature (id integer,name text,prev_label_id integer,label_id integer,weight float);"
155  plpy.execute(query);
156 
157  # dictionary table
158  query = "DROP TABLE IF EXISTS MADLIB_SCHEMA.crf_dictionary;" + \
159  "CREATE TABLE MADLIB_SCHEMA.crf_dictionary(token text,total integer);"
160  plpy.execute(query);
161 
162  query = "DROP TABLE IF EXISTS MADLIB_SCHEMA.featuretbl;" + \
163  "CREATE TABLE MADLIB_SCHEMA.featuretbl(doc_id integer,f_size FLOAT8,sparse_r FLOAT8[],dense_m FLOAT8[],sparse_m FLOAT8[]);"
164  plpy.execute(query);
165 
166  query = "DROP TABLE IF EXISTS MADLIB_SCHEMA.crf_feature_dic;" + \
167  "CREATE TABLE MADLIB_SCHEMA.crf_feature_dic(f_index integer, f_name text, feature integer[]);"
168  plpy.execute(query);
169 
170 $$ LANGUAGE plpythonu STRICT;
171 
172 
173 /**
174 
175 @input
176 
177 -# Prepare an input test data segment table, e.g.:
178 - CREATE TABLE test_segmenttbl (start_pos integer,doc_id integer,seg_text text, max_pos integer)
179 \verbatim
180 sql> select * from test_segmenttbl order by doc_id, start_pos;
181 start_pos | doc_id | seg_text | max_pos
182 ----------+---------+--------------+-------------
183  0 | 1 | the | 26
184  1 | 1 | madlib | 26
185  2 | 1 | mission | 26
186  3 | 1 | : | 26
187  4 | 1 | to | 26
188  5 | 1 | foster | 26
189  6 | 1 | widespread | 26
190  7 | 1 | development | 26
191  8 | 1 | of | 26
192  9 | 1 | scalable | 26
193  10 | 1 | analytic | 26
194  11 | 1 | skills | 26
195  12 | 1 | , | 26
196  13 | 1 | by | 26
197  ...
198  24 | 1 | open-source | 26
199  25 | 1 | development | 26
200  26 | 1 | . | 26
201 \endverbatim
202 
203 @usage
204 - create tables and import data to the database
205  SELECT madlib.crf_test_data('/path/to/modeldata')
206 
207 */
208 
209 CREATE OR REPLACE FUNCTION MADLIB_SCHEMA.crf_test_data(datapath text) RETURNS void AS
210 $$
211  # tokenized document
212  query = "DROP TABLE IF EXISTS MADLIB_SCHEMA.test_segmenttbl CASCADE;" + \
213  "CREATE TABLE MADLIB_SCHEMA.test_segmenttbl (start_pos integer,doc_id integer,seg_text text, max_pos integer)";
214  plpy.execute(query);
215 
216  # R factor table
217  query = "DROP TABLE IF EXISTS MADLIB_SCHEMA.viterbi_rtbl;" + \
218  "CREATE TABLE MADLIB_SCHEMA.viterbi_rtbl (seg_text text, label integer, score integer)";
219  plpy.execute(query);
220 
221  # M factor table
222  query = "DROP TABLE IF EXISTS MADLIB_SCHEMA.viterbi_mtbl;" + \
223  "CREATE TABLE MADLIB_SCHEMA.viterbi_mtbl (score integer[])";
224  plpy.execute(query);
225 
226  # import tokenized document to the segment table
227  query = "COPY MADLIB_SCHEMA.test_segmenttbl (start_pos,doc_id,seg_text,max_pos) FROM '" + datapath + "/crf_testdata.tab'";
228  plpy.execute(query);
229 
230 $$ language plpythonu STRICT;