This module implements a sparse vector data type, named "svec", which provides compressed storage of vectors that have many duplicate elements.
Arrays of floating point numbers for various calculations sometimes have long runs of zeros (or some other default value). This is common in applications like scientific computing, retail optimization, and text processing. Each floating point number takes 8 bytes of storage in memory and/or disk, so saving those zeros is often worthwhile. There are also many computations that can benefit from skipping over the zeros.
Consider, for example, the following array of doubles stored as a Postgres/Greenplum "float8[]" data type:
'{0, 33,...40,000 zeros..., 12, 22 }'::float8[]
This array would occupy slightly more than 320KB of memory or disk, most of it zeros. Even if we were to exploit the null bitmap and store the zeros as nulls, we would still end up with a 5KB null bitmap, which is still not nearly as memory efficient as we'd like. Also, as we perform various operations on the array, we do work on 40,000 fields that turn out to be unimportant.
To solve the problems associated with the processing of vectors discussed above, the svec type employs a simple Run Length Encoding (RLE) scheme to represent sparse vectors as pairs of count-value arrays. For example, the array above would be represented as
'{1,1,40000,1,1}:{0,33,0,12,22}'::madlib.svec
which says there is 1 occurrence of 0, followed by 1 occurrence of 33, followed by 40,000 occurrences of 0, etc. This uses just 5 integers and 5 floating point numbers to store the array. Further, it is easy to implement vector operations that can take advantage of the RLE representation to make computations faster. The SVEC module provides a library of such functions.
The current version only supports sparse vectors of float8 values. Future versions will support other base types.
An SVEC can be constructed directly with a constant expression, as follows:
SELECT '{n1,n2,...,nk}:{v1,v2,...vk}'::madlib.svec;
where n1,n2,...,nk
specifies the counts for the values v1,v2,...,vk
.
A float array can be cast to an SVEC:
SELECT ('{v1,v2,...vk}'::float[])::madlib.svec;
An SVEC can be created with an aggregation:
SELECT madlib.svec_agg(v1) FROM generate_series(1,k);
An SVEC can be created using the madlib.svec_cast_positions_float8arr()
function by supplying an array of positions and an array of values at those positions:
SELECT madlib.svec_cast_positions_float8arr( array[n1,n2,...nk], -- positions of values in vector array[v1,v2,...vk], -- values at each position length, -- length of vector base) -- value at unspecified positions
For example, the following expression:
SELECT madlib.svec_cast_positions_float8arr( array[1,3,5], array[2,4,6], 10, 0.0)
produces this SVEC:
svec_cast_positions_float8arr ------------------------------ {1,1,1,1,1,5}:{2,0,4,0,6,0}
Add madlib to the search_path to use the svec operators defined in the module.
The function accepts two tables as input, dictionary table and documents table, and produces the specified output table containing sparse vectors for the represented documents (in documents table).
madlib.gen_doc_svecs(output_tbl, dictionary_tbl, dict_id_col, dict_term_col, documents_tbl, doc_id_col, doc_term_col, doc_term_info_col )
Arguments
TEXT. Name of the output table to be created containing the sparse vector representation of the documents. It has the following columns:
doc_id | __TYPE_DOC__. Document id. __TYPE_DOC__: Column type depends on the type of doc_id_col in documents_tbl . |
---|---|
sparse_vector | MADlib.svec. Corresponding sparse vector representation. |
TEXT. Name of the dictionary table containing features.
dict_id_col | TEXT. Name of the id column in the dictionary_tbl . Expected Type: INTEGER or BIGINT. NOTE: Values must be continuous ranging from 0 to total number of elements in the dictionary - 1. |
---|---|
dict_term_col | TEXT. Name of the column containing term (features) in dictionary_tbl . |
doc_id_col | TEXT. Name of the id column in the documents_tbl . |
---|---|
doc_term_col | TEXT. Name of the term column in the documents_tbl . |
doc_term_info_col | TEXT. Name of the term info column in documents_tbl . The expected type of this column should be: - INTEGER, BIGINT or DOUBLE PRECISION: Values directly used to populate vector. - ARRAY: Length of the array used to populate the vector. ** For an example use case on using these types of column types, please refer to the example below. |
Example:
Consider a corpus consisting of set of documents consisting of features (terms) along with doc ids:
1, {this,is,one,document,in,the,corpus} 2, {i,am,the,second,document,in,the,corpus} 3, {being,third,never,really,bothered,me,until,now} 4, {the,document,before,me,is,the,third,document}
documents_table:
SELECT * FROM documents_table ORDER BY id;Result:
id | term | count id | term | positions ----+----------+------- ----+----------+----------- 1 | is | 1 1 | is | {1} 1 | in | 1 1 | in | {4} 1 | one | 1 1 | one | {2} 1 | this | 1 1 | this | {0} 1 | the | 1 1 | the | {5} 1 | document | 1 1 | document | {3} 1 | corpus | 1 1 | corpus | {6} 2 | second | 1 2 | second | {3} 2 | document | 1 2 | document | {4} 2 | corpus | 1 2 | corpus | {7} . | ... | .. . | ... | ... 4 | document | 2 4 | document | {1,7} ...
SELECT * FROM dictionary_table ORDER BY id;Result:
id | term ----+---------- 0 | am 1 | before 2 | being 3 | bothered 4 | corpus 5 | document 6 | i 7 | in 8 | is 9 | me ...
doc_term_info_col
(count) of type INTEGER: SELECT * FROM madlib.gen_doc_svecs('svec_output', 'dictionary_table', 'id', 'term', 'documents_table', 'id', 'term', 'count');
doc_term_info_col
(positions) of type ARRAY: SELECT * FROM madlib.gen_doc_svecs('svec_output', 'dictionary_table', 'id', 'term', 'documents_table', 'id', 'term', 'positions');Result:
gen_doc_svecs -------------------------------------------------------------------------------------- Created table svec_output (doc_id, sparse_vector) containing sparse vectors (1 row)
SELECT * FROM svec_output ORDER by doc_id;Result:
doc_id | sparse_vector --------+------------------------------------------------- 1 | {4,2,1,2,3,1,2,1,1,1,1}:{0,1,0,1,0,1,0,1,0,1,0} 2 | {1,3,4,6,1,1,3}:{1,0,1,0,1,2,0} 3 | {2,2,5,3,1,1,2,1,1,1}:{0,1,0,1,0,1,0,1,0,1} 4 | {1,1,3,1,2,2,5,1,1,2}:{0,1,0,2,0,1,0,2,1,0} (4 rows)
See the file svec.sql_in for complete syntax.
We can use operations with svec type like <, >, *, **, /, =, +, SUM, etc, and they have meanings associated with typical vector operations. For example, the plus (+) operator adds each of the terms of two vectors having the same dimension together.
SELECT ('{0,1,5}'::float8[]::madlib.svec + '{4,3,2}'::float8[]::madlib.svec)::float8[];
Result:
float8 -------- {4,4,7}
Without the casting into float8[] at the end, we get:
SELECT '{0,1,5}'::float8[]::madlib.svec + '{4,3,2}'::float8[]::madlib.svec;
Result:
?column? --------- {2,1}:{4,7}
A dot product (%*%) between the two vectors will result in a scalar result of type float8. The dot product should be (0*4 + 1*3 + 5*2) = 13, like this:
SELECT '{0,1,5}'::float8[]::madlib.svec %*% '{4,3,2}'::float8[]::madlib.svec;
?column? --------- 13
Special vector aggregate functions are also available. SUM is self explanatory. SVEC_COUNT_NONZERO evaluates the count of non-zero terms in each column found in a set of n-dimensional svecs and returns an svec with the counts. For instance, if we have the vectors {0,1,5}, {10,0,3},{0,0,3},{0,1,0}, then executing the SVEC_COUNT_NONZERO() aggregate function would result in {1,2,3}:
CREATE TABLE list (a madlib.svec); INSERT INTO list VALUES ('{0,1,5}'::float8[]), ('{10,0,3}'::float8[]), ('{0,0,3}'::float8[]),('{0,1,0}'::float8[]); SELECT madlib.svec_count_nonzero(a)::float8[] FROM list;
Result:
svec_count_nonzero ---------------- {1,2,3}
We do not use null bitmaps in the svec data type. A null value in an svec is represented explicitly as an NVP (No Value Present) value. For example, we have:
SELECT '{1,2,3}:{4,null,5}'::madlib.svec;
Result:
svec ------------------ {1,2,3}:{4,NVP,5}
Adding svecs with null values results in NVPs in the sum:
SELECT '{1,2,3}:{4,null,5}'::madlib.svec + '{2,2,2}:{8,9,10}'::madlib.svec;
Result:
?column? ------------------------- {1,2,1,2}:{12,NVP,14,15}
An element of an svec can be accessed using the svec_proj() function, which takes an svec and the index of the element desired.
SELECT madlib.svec_proj('{1,2,3}:{4,5,6}'::madlib.svec, 1) + madlib.svec_proj('{4,5,6}:{1,2,3}'::madlib.svec, 15);
Result:
?column? --------- 7
A subvector of an svec can be accessed using the svec_subvec() function, which takes an svec and the start and end index of the subvector desired.
SELECT madlib.svec_subvec('{2,4,6}:{1,3,5}'::madlib.svec, 2, 11);
Result:
svec_subvec ---------------- {1,4,5}:{1,3,5}
The elements/subvector of an svec can be changed using the function svec_change(). It takes three arguments: an m-dimensional svec sv1, a start index j, and an n-dimensional svec sv2 such that j + n - 1 <= m, and returns an svec like sv1 but with the subvector sv1[j:j+n-1] replaced by sv2. An example follows:
SELECT madlib.svec_change('{1,2,3}:{4,5,6}'::madlib.svec,3,'{2}:{3}'::madlib.svec);
Result:
svec_change -------------------- {1,1,2,2}:{4,5,3,6}
There are also higher-order functions for processing svecs. For example, the following is the corresponding function for lapply() in R.
SELECT madlib.svec_lapply('sqrt', '{1,2,3}:{4,5,6}'::madlib.svec);
Result:
svec_lapply ---------------------------------------------- {1,2,3}:{2,2.23606797749979,2.44948974278318}
The full list of functions available for operating on svecs are available in svec.sql-in.
A More Extensive Example
For a text classification example, let's assume we have a dictionary composed of words in a sorted text array:
CREATE TABLE features (a text[]); INSERT INTO features VALUES ('{am,before,being,bothered,corpus,document,i,in,is,me, never,now,one,really,second,the,third,this,until}');
We have a set of documents, each represented as an array of words:
CREATE TABLE documents(a int,b text[]); INSERT INTO documents VALUES (1,'{this,is,one,document,in,the,corpus}'), (2,'{i,am,the,second,document,in,the,corpus}'), (3,'{being,third,never,really,bothered,me,until,now}'), (4,'{the,document,before,me,is,the,third,document}');
Now we have a dictionary and some documents, we would like to do some document categorization using vector arithmetic on word counts and proportions of dictionary words in each document.
To start this process, we'll need to find the dictionary words in each document. We'll prepare what is called a Sparse Feature Vector or SFV for each document. An SFV is a vector of dimension N, where N is the number of dictionary words, and in each cell of an SFV is a count of each dictionary word in the document.
Inside the sparse vector library, we have a function that will create an SFV from a document, so we can just do this (For a more efficient way for converting documents into sparse vectors, especially for larger datasets, please refer to Document Vectorization into Sparse Vectors):
SELECT madlib.svec_sfv((SELECT a FROM features LIMIT 1),b)::float8[] FROM documents;
Result:
svec_sfv ---------------------------------------- {0,0,0,0,1,1,0,1,1,0,0,0,1,0,0,1,0,1,0} {0,0,1,1,0,0,0,0,0,1,1,1,0,1,0,0,1,0,1} {1,0,0,0,1,1,1,1,0,0,0,0,0,0,1,2,0,0,0} {0,1,0,0,0,2,0,0,1,1,0,0,0,0,0,2,1,0,0}
Note that the output of madlib.svec_sfv() is an svec for each document containing the count of each of the dictionary words in the ordinal positions of the dictionary. This can more easily be understood by lining up the feature vector and text like this:
SELECT madlib.svec_sfv((SELECT a FROM features LIMIT 1),b)::float8[] , b FROM documents;
Result:
svec_sfv | b ----------------------------------------+-------------------------------------------------- {1,0,0,0,1,1,1,1,0,0,0,0,0,0,1,2,0,0,0} | {i,am,the,second,document,in,the,corpus} {0,1,0,0,0,2,0,0,1,1,0,0,0,0,0,2,1,0,0} | {the,document,before,me,is,the,third,document} {0,0,0,0,1,1,0,1,1,0,0,0,1,0,0,1,0,1,0} | {this,is,one,document,in,the,corpus} {0,0,1,1,0,0,0,0,0,1,1,1,0,1,0,0,1,0,1} | {being,third,never,really,bothered,me,until,now}
SELECT * FROM features;
a ------------------------------------------------------------------------------------------------------- {am,before,being,bothered,corpus,document,i,in,is,me,never,now,one,really,second,the,third,this,until}
Now when we look at the document "i am the second document in the corpus", its SFV is {1,3*0,1,1,1,1,6*0,1,2}. The word "am" is the first ordinate in the dictionary and there is 1 instance of it in the SFV. The word "before" has no instances in the document, so its value is "0" and so on.
The function madlib.svec_sfv() can process large numbers of documents into their SFVs in parallel at high speed.
The rest of the categorization process is all vector math. The actual count is hardly ever used. Instead, it's turned into a weight. The most common weight is called tf/idf for Term Frequency / Inverse Document Frequency. The calculation for a given term in a given document is
{#Times in document} * log {#Documents / #Documents the term appears in}.
For instance, the term "document" in document A would have weight 1 * log (4/3). In document D, it would have weight 2 * log (4/3). Terms that appear in every document would have tf/idf weight 0, since log (4/4) = log(1) = 0. (Our example has no term like that.) That usually sends a lot of values to 0.
For this part of the processing, we'll need to have a sparse vector of the dictionary dimension (19) with the values
log(#documents/#Documents each term appears in).
There will be one such vector for the whole list of documents (aka the "corpus"). The #documents is just a count of all of the documents, in this case 4, but there is one divisor for each dictionary word and its value is the count of all the times that word appears in the document. This single vector for the whole corpus can then be scalar product multiplied by each document SFV to produce the Term Frequency/Inverse Document Frequency weights.
This can be done as follows:
CREATE TABLE corpus AS (SELECT a, madlib.svec_sfv((SELECT a FROM features LIMIT 1),b) sfv FROM documents); CREATE TABLE weights AS (SELECT a docnum, madlib.svec_mult(sfv, logidf) tf_idf FROM (SELECT madlib.svec_log(madlib.svec_div(count(sfv)::madlib.svec,madlib.svec_count_nonzero(sfv))) logidf FROM corpus) foo, corpus ORDER BYdocnum); SELECT * FROM weights;
Result
docnum | tf_idf ------+---------------------------------------------------------------------- 1 | {4,1,1,1,2,3,1,2,1,1,1,1}:{0,0.69,0.28,0,0.69,0,1.38,0,0.28,0,1.38,0} 2 | {1,3,1,1,1,1,6,1,1,3}:{1.38,0,0.69,0.28,1.38,0.69,0,1.38,0.57,0} 3 | {2,2,5,1,2,1,1,2,1,1,1}:{0,1.38,0,0.69,1.38,0,1.38,0,0.69,0,1.38} 4 | {1,1,3,1,2,2,5,1,1,2}:{0,1.38,0,0.57,0,0.69,0,0.57,0.69,0}
We can now get the "angular distance" between one document and the rest of the documents using the ACOS of the dot product of the document vectors: The following calculates the angular distance between the first document and each of the other documents:
SELECT docnum, 180. * ( ACOS( madlib.svec_dmin( 1., madlib.svec_dot(tf_idf, testdoc) / (madlib.svec_l2norm(tf_idf)*madlib.svec_l2norm(testdoc))))/3.141592654) angular_distance FROM weights,(SELECT tf_idf testdoc FROM weights WHERE docnum = 1 LIMIT 1) foo ORDER BY 1;
Result:
docnum | angular_distance -------+------------------ 1 | 0 2 | 78.8235846096986 3 | 89.9999999882484 4 | 80.0232034288617
We can see that the angular distance between document 1 and itself is 0 degrees and between document 1 and 3 is 90 degrees because they share no features at all. The angular distance can now be plugged into machine learning algorithms that rely on a distance measure between data points.
SVEC also provides functionality for declaring array given an array of positions and array of values, intermediate values betweens those are declared to be base value that user provides in the same function call. In the example below the fist array of integers represents the positions for the array two (array of floats). Positions do not need to come in the sorted order. Third value represents desired maximum size of the array. This assures that array is of that size even if last position is not. If max size < 1 that value is ignored and array will end at the last position in the position vector. Final value is a float representing the base value to be used between the declared ones (0 would be a common candidate):
SELECT madlib.svec_cast_positions_float8arr(ARRAY[1,2,7,5,87],ARRAY[.1,.2,.7,.5,.87],90,0.0);
Result:
svec_cast_positions_float8arr ---------------------------------------------------- {1,1,2,1,1,1,79,1,3}:{0.1,0.2,0,0.5,0,0.7,0,0.87,0} (1 row)
Other examples of svecs usage can be found in the k-means module, k-Means Clustering.
File svec.sql_in documenting the SQL functions.