blob: 5ee8acbf571247d721d5885218451bda3c876338 [file] [log] [blame]
<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd">
<html xmlns="http://www.w3.org/1999/xhtml">
<head>
<meta http-equiv="Content-Type" content="text/xhtml;charset=UTF-8"/>
<title>MADlib: quantile.sql_in Source File</title>
<link href="tabs.css" rel="stylesheet" type="text/css"/>
<link href="doxygen.css" rel="stylesheet" type="text/css" />
<link href="navtree.css" rel="stylesheet" type="text/css"/>
<script type="text/javascript" src="jquery.js"></script>
<script type="text/javascript" src="resize.js"></script>
<script type="text/javascript" src="navtree.js"></script>
<script type="text/javascript">
$(document).ready(initResizable);
</script>
<link href="search/search.css" rel="stylesheet" type="text/css"/>
<script type="text/javascript" src="search/search.js"></script>
<script type="text/javascript">
$(document).ready(function() { searchBox.OnSelectItem(0); });
</script>
<script src="../mathjax/MathJax.js">
MathJax.Hub.Config({
extensions: ["tex2jax.js", "TeX/AMSmath.js", "TeX/AMSsymbols.js"],
jax: ["input/TeX","output/HTML-CSS"],
});
</script>
</head>
<body>
<div id="top"><!-- do not remove this div! -->
<div id="titlearea">
<table cellspacing="0" cellpadding="0">
<tbody>
<tr style="height: 56px;">
<td style="padding-left: 0.5em;">
<div id="projectname">MADlib
&#160;<span id="projectnumber">0.6</span> <span style="font-size:10pt; font-style:italic"><a href="../latest/./quantile_8sql__in_source.html"> A newer version is available</a></span>
</div>
<div id="projectbrief">User Documentation</div>
</td>
</tr>
</tbody>
</table>
</div>
<!-- Generated by Doxygen 1.7.5.1 -->
<script type="text/javascript">
var searchBox = new SearchBox("searchBox", "search",false,'Search');
</script>
<script type="text/javascript" src="dynsections.js"></script>
<div id="navrow1" class="tabs">
<ul class="tablist">
<li><a href="index.html"><span>Main&#160;Page</span></a></li>
<li><a href="modules.html"><span>Modules</span></a></li>
<li class="current"><a href="files.html"><span>Files</span></a></li>
<li>
<div id="MSearchBox" class="MSearchBoxInactive">
<span class="left">
<img id="MSearchSelect" src="search/mag_sel.png"
onmouseover="return searchBox.OnSearchSelectShow()"
onmouseout="return searchBox.OnSearchSelectHide()"
alt=""/>
<input type="text" id="MSearchField" value="Search" accesskey="S"
onfocus="searchBox.OnSearchFieldFocus(true)"
onblur="searchBox.OnSearchFieldFocus(false)"
onkeyup="searchBox.OnSearchFieldChange(event)"/>
</span><span class="right">
<a id="MSearchClose" href="javascript:searchBox.CloseResultsWindow()"><img id="MSearchCloseImg" border="0" src="search/close.png" alt=""/></a>
</span>
</div>
</li>
</ul>
</div>
<div id="navrow2" class="tabs2">
<ul class="tablist">
<li><a href="files.html"><span>File&#160;List</span></a></li>
<li><a href="globals.html"><span>File&#160;Members</span></a></li>
</ul>
</div>
</div>
<div id="side-nav" class="ui-resizable side-nav-resizable">
<div id="nav-tree">
<div id="nav-tree-contents">
</div>
</div>
<div id="splitbar" style="-moz-user-select:none;"
class="ui-resizable-handle">
</div>
</div>
<script type="text/javascript">
initNavTree('quantile_8sql__in.html','');
</script>
<div id="doc-content">
<div class="header">
<div class="headertitle">
<div class="title">quantile.sql_in</div> </div>
</div>
<div class="contents">
<a href="quantile_8sql__in.html">Go to the documentation of this file.</a><div class="fragment"><pre class="fragment"><a name="l00001"></a>00001 <span class="comment">/* ----------------------------------------------------------------------- */</span><span class="comment">/**</span>
<a name="l00002"></a>00002 <span class="comment"> *</span>
<a name="l00003"></a>00003 <span class="comment"> * @file quantile.sql_in</span>
<a name="l00004"></a>00004 <span class="comment"> *</span>
<a name="l00005"></a>00005 <span class="comment"> * @brief SQL function for Quantile</span>
<a name="l00006"></a>00006 <span class="comment"> * @date January 2011</span>
<a name="l00007"></a>00007 <span class="comment"> *</span>
<a name="l00008"></a>00008 <span class="comment"> * @sa For a brief introduction to quantiles, see the module</span>
<a name="l00009"></a>00009 <span class="comment"> * description \ref grp_quantile.</span>
<a name="l00010"></a>00010 <span class="comment"> *</span>
<a name="l00011"></a>00011 <span class="comment"> */</span><span class="comment">/* ----------------------------------------------------------------------- */</span>
<a name="l00012"></a>00012 <span class="comment"></span>
<a name="l00013"></a>00013 <span class="comment">/**</span>
<a name="l00014"></a>00014 <span class="comment">@addtogroup grp_quantile</span>
<a name="l00015"></a>00015 <span class="comment"></span>
<a name="l00016"></a>00016 <span class="comment">@about</span>
<a name="l00017"></a>00017 <span class="comment">This function computes the specified quantile value. It reads the name of the</span>
<a name="l00018"></a>00018 <span class="comment">table, the specific column, and computes the quantile value based on the</span>
<a name="l00019"></a>00019 <span class="comment">fraction specified as the third argument.</span>
<a name="l00020"></a>00020 <span class="comment"></span>
<a name="l00021"></a>00021 <span class="comment">For an implementation of quantile using sketches, check out the cmsketch_centile()</span>
<a name="l00022"></a>00022 <span class="comment">aggregate in the \ref grp_countmin module.</span>
<a name="l00023"></a>00023 <span class="comment"></span>
<a name="l00024"></a>00024 <span class="comment">@implementation</span>
<a name="l00025"></a>00025 <span class="comment">There are two implementations of quantile available depending on the size of the table. &lt;tt&gt;quantile&lt;/tt&gt; is best used for small tables (e.g. less than 5000 rows, with 1-2 columns in total). For larger tables,</span>
<a name="l00026"></a>00026 <span class="comment">consider using &lt;tt&gt;quantile_big&lt;/tt&gt; instead.</span>
<a name="l00027"></a>00027 <span class="comment"></span>
<a name="l00028"></a>00028 <span class="comment">@usage</span>
<a name="l00029"></a>00029 <span class="comment">&lt;pre&gt;SELECT * FROM quantile( &#39;&lt;em&gt;table_name&lt;/em&gt;&#39;, &#39;&lt;em&gt;col_name&lt;/em&gt;&#39;, &lt;em&gt;quantile&lt;/em&gt;);&lt;/pre&gt;</span>
<a name="l00030"></a>00030 <span class="comment">&lt;pre&gt;SELECT * FROM quantile_big( &#39;&lt;em&gt;table_name&lt;/em&gt;&#39;, &#39;&lt;em&gt;col_name&lt;/em&gt;&#39;, &lt;em&gt;quantile&lt;/em&gt;);&lt;/pre&gt;</span>
<a name="l00031"></a>00031 <span class="comment"></span>
<a name="l00032"></a>00032 <span class="comment">@examp</span>
<a name="l00033"></a>00033 <span class="comment"></span>
<a name="l00034"></a>00034 <span class="comment">-# Prepare some input:</span>
<a name="l00035"></a>00035 <span class="comment">\verbatim</span>
<a name="l00036"></a>00036 <span class="comment">sql&gt; CREATE TABLE tab1 AS SELECT generate_series( 1,1000) as col1;</span>
<a name="l00037"></a>00037 <span class="comment">\endverbatim</span>
<a name="l00038"></a>00038 <span class="comment">-# Run the quantile() function:\n</span>
<a name="l00039"></a>00039 <span class="comment">\verbatim</span>
<a name="l00040"></a>00040 <span class="comment">sql&gt; SELECT quantile( &#39;tab1&#39;, &#39;col1&#39;, .3);</span>
<a name="l00041"></a>00041 <span class="comment"></span>
<a name="l00042"></a>00042 <span class="comment"> quantile </span>
<a name="l00043"></a>00043 <span class="comment">--------------</span>
<a name="l00044"></a>00044 <span class="comment"> 301.48046875</span>
<a name="l00045"></a>00045 <span class="comment">(1 row)</span>
<a name="l00046"></a>00046 <span class="comment">\endverbatim</span>
<a name="l00047"></a>00047 <span class="comment"></span>
<a name="l00048"></a>00048 <span class="comment">@sa File quantile.sql_in documenting the SQL function.\n\n</span>
<a name="l00049"></a>00049 <span class="comment">Module grp_countmin for an approximate quantile implementation.</span>
<a name="l00050"></a>00050 <span class="comment">*/</span>
<a name="l00051"></a>00051
<a name="l00052"></a>00052 <span class="comment"></span>
<a name="l00053"></a>00053 <span class="comment">/**</span>
<a name="l00054"></a>00054 <span class="comment"> * @brief Computes quantile</span>
<a name="l00055"></a>00055 <span class="comment"> *</span>
<a name="l00056"></a>00056 <span class="comment"> * @param table_name name of the table from which quantile is to be taken</span>
<a name="l00057"></a>00057 <span class="comment"> * @param col_name name of the column that is to be used for quantile calculation</span>
<a name="l00058"></a>00058 <span class="comment"> * @param quantile desired quantile value \f$ \in (0,1) \f$</span>
<a name="l00059"></a>00059 <span class="comment"> * @returns The quantile value</span>
<a name="l00060"></a>00060 <span class="comment"> *</span>
<a name="l00061"></a>00061 <span class="comment"> * This function computes the specified quantile value. It reads the name of the</span>
<a name="l00062"></a>00062 <span class="comment"> * table, the specific column, and computes the quantile value based on the</span>
<a name="l00063"></a>00063 <span class="comment"> * fraction specified as the third argument. The functionality is the same as &lt;tt&gt;quantile&lt;/tt&gt; except this implementation is designed to work more efficiently with large tables.</span>
<a name="l00064"></a>00064 <span class="comment"> */</span>
<a name="l00065"></a><a class="code" href="quantile_8sql__in.html#a154435ddf6200110013dc05b1a6207fe">00065</a> CREATE OR REPLACE FUNCTION MADLIB_SCHEMA.quantile_big(table_name TEXT, col_name TEXT, <a class="code" href="quantile_8sql__in.html#a6955e44659a0817803ab7a11a9a7e8a5" title="Computes quantile.">quantile</a> FLOAT) RETURNS FLOAT AS $$
<a name="l00066"></a>00066 declare
<a name="l00067"></a>00067 size FLOAT[];
<a name="l00068"></a>00068 count BIGINT;
<a name="l00069"></a>00069 increment INT := 0;
<a name="l00070"></a>00070 curr_old BIGINT;
<a name="l00071"></a>00071 last_values FLOAT[];
<a name="l00072"></a>00072 last_count BIGINT;
<a name="l00073"></a>00073 last_value1 FLOAT;
<a name="l00074"></a>00074 last_count1 BIGINT;
<a name="l00075"></a>00075 last_value2 FLOAT;
<a name="l00076"></a>00076 last_count2 BIGINT;
<a name="l00077"></a>00077 quantile_size BIGINT;
<a name="l00078"></a>00078 full_size BIGINT;
<a name="l00079"></a>00079 rows_removed BIGINT := 0;
<a name="l00080"></a>00080 Begin
<a name="l00081"></a>00081 <span class="comment">/*</span>
<a name="l00082"></a>00082 <span class="comment"> This portion computes basic statistics on the table, finding:</span>
<a name="l00083"></a>00083 <span class="comment"> MIN value</span>
<a name="l00084"></a>00084 <span class="comment"> AVG value</span>
<a name="l00085"></a>00085 <span class="comment"> MAX value</span>
<a name="l00086"></a>00086 <span class="comment"> COOUNT of the elemens</span>
<a name="l00087"></a>00087 <span class="comment"> Which at stored in that order into &#39;size&#39;, count object</span>
<a name="l00088"></a>00088 <span class="comment"> &#39;quantile_size&#39; is computed in terms of element count</span>
<a name="l00089"></a>00089 <span class="comment"> */</span>
<a name="l00090"></a>00090 EXECUTE <span class="stringliteral">&#39;SELECT array[MIN(&#39;</span>||col_name||<span class="stringliteral">&#39;), AVG(&#39;</span>||col_name||<span class="stringliteral">&#39;), MAX(&#39;</span>||col_name||<span class="stringliteral">&#39;)], COUNT(*) FROM &#39;</span>||table_name||<span class="charliteral">&#39; &#39;</span> INTO size, count;
<a name="l00091"></a>00091 quantile_size = (count*<a class="code" href="quantile_8sql__in.html#a6955e44659a0817803ab7a11a9a7e8a5" title="Computes quantile.">quantile</a>)::BIGINT;
<a name="l00092"></a>00092 full_size = count;
<a name="l00093"></a>00093
<a name="l00094"></a>00094 -- check <span class="keywordflow">for</span> bad input
<a name="l00095"></a>00095 IF(<a class="code" href="quantile_8sql__in.html#a6955e44659a0817803ab7a11a9a7e8a5" title="Computes quantile.">quantile</a> &lt; 0) OR (<a class="code" href="quantile_8sql__in.html#a6955e44659a0817803ab7a11a9a7e8a5" title="Computes quantile.">quantile</a> &gt;= 1) THEN
<a name="l00096"></a>00096 RAISE EXCEPTION &#39;Quantile should be between 0 and 0.99&#39;;
<a name="l00097"></a>00097 ELSIF(<a class="code" href="quantile_8sql__in.html#a6955e44659a0817803ab7a11a9a7e8a5" title="Computes quantile.">quantile</a> = 0) THEN
<a name="l00098"></a>00098 RETURN size[1];
<a name="l00099"></a>00099 END IF;
<a name="l00100"></a>00100
<a name="l00101"></a>00101 -- create some temp tables to use as swap
<a name="l00102"></a>00102 DROP TABLE IF EXISTS temptable0;
<a name="l00103"></a>00103 CREATE TEMP TABLE temptable0(val FLOAT);
<a name="l00104"></a>00104
<a name="l00105"></a>00105 DROP TABLE IF EXISTS temptable1;
<a name="l00106"></a>00106 CREATE TEMP TABLE temptable1(val FLOAT);
<a name="l00107"></a>00107
<a name="l00108"></a>00108
<a name="l00109"></a>00109 <span class="comment">/*</span>
<a name="l00110"></a>00110 <span class="comment"> This is the main loop of the algorithm. Its goal is to do a binarry search over the table to find the value that is the closest to the position corresponding to the</span>
<a name="l00111"></a>00111 <span class="comment"> quantile size.</span>
<a name="l00112"></a>00112 <span class="comment"></span>
<a name="l00113"></a>00113 <span class="comment"> In each itteration for a given value &#39;size[2]&#39; following are computed:</span>
<a name="l00114"></a>00114 <span class="comment"> MIN value less than or equal to &#39;size[2]&#39;</span>
<a name="l00115"></a>00115 <span class="comment"> AVERAGE value less than or equal to &#39;size[2]&#39;</span>
<a name="l00116"></a>00116 <span class="comment"> MAX value less than or equal to &#39;size[2]&#39;</span>
<a name="l00117"></a>00117 <span class="comment"> COUNT of the values less than or equal to &#39;size[2]&#39;</span>
<a name="l00118"></a>00118 <span class="comment"> This results are stored into &#39;last_values&#39;, last_count in that order</span>
<a name="l00119"></a>00119 <span class="comment"> */</span>
<a name="l00120"></a>00120 LOOP
<a name="l00121"></a>00121 IF(increment = 0) THEN
<a name="l00122"></a>00122 EXECUTE &#39;SELECT ARRAY[MIN(&#39;||col_name||&#39;),AVG(&#39;||col_name||&#39;),MAX(&#39;||col_name||&#39;)],COUNT(*) FROM &#39;||table_name||&#39; WHERE &#39;||col_name||&#39; &lt;= &#39;||size[2]||&#39;;&#39; INTO last_values, last_count;
<a name="l00123"></a>00123 ELSE
<a name="l00124"></a>00124 EXECUTE &#39;SELECT ARRAY[MIN(val),AVG(val),MAX(val)],COUNT(*) FROM temptable&#39;||increment%2||&#39; WHERE val &lt;= &#39;||size[2]||&#39;;&#39; INTO last_values, last_count;
<a name="l00125"></a>00125 END IF;
<a name="l00126"></a>00126 last_count = last_count + rows_removed;
<a name="l00127"></a>00127
<a name="l00128"></a>00128
<a name="l00129"></a>00129 IF(last_count=rows_removed) THEN
<a name="l00130"></a>00130 <span class="comment">/*</span>
<a name="l00131"></a>00131 <span class="comment"> If there are no more rows left, we exit.</span>
<a name="l00132"></a>00132 <span class="comment"> */</span>
<a name="l00133"></a>00133 EXIT;
<a name="l00134"></a>00134
<a name="l00135"></a>00135 ELSIF((increment &gt; 0)AND(curr_old = last_count)) THEN
<a name="l00136"></a>00136 <span class="comment">/*</span>
<a name="l00137"></a>00137 <span class="comment"> We will exit the loop if there was not change in the count from previous itteration</span>
<a name="l00138"></a>00138 <span class="comment"> which mean that process will make no further progress.</span>
<a name="l00139"></a>00139 <span class="comment"> */</span>
<a name="l00140"></a>00140 EXIT;
<a name="l00141"></a>00141 ELSIF((last_count - quantile_size) &gt; 1) THEN
<a name="l00142"></a>00142 <span class="comment">/*</span>
<a name="l00143"></a>00143 <span class="comment"> If current COUNT is greater than &#39;size[2]&#39; we will reduce the value of &#39;size[2]&#39;</span>
<a name="l00144"></a>00144 <span class="comment"> in binarry search fashion. And then update upper limit to our search the max value observed in this round</span>
<a name="l00145"></a>00145 <span class="comment"> */</span>
<a name="l00146"></a>00146 size[2] = (last_values[3]+size[1])/2.0;
<a name="l00147"></a>00147 size[3] = last_values[3];
<a name="l00148"></a>00148
<a name="l00149"></a>00149 --remove all rows that are larger than new max
<a name="l00150"></a>00150 IF(increment = 0) THEN
<a name="l00151"></a>00151 EXECUTE &#39;INSERT INTO temptable&#39;||(increment+1)%2||&#39; SELECT &#39;||col_name||&#39; FROM &#39;||table_name||&#39; WHERE &#39;||col_name||&#39; &lt;= &#39;||size[3]||&#39;;&#39;;
<a name="l00152"></a>00152 ELSE
<a name="l00153"></a>00153 EXECUTE &#39;INSERT INTO temptable&#39;||(increment+1)%2||&#39; SELECT val FROM temptable&#39;||increment%2||&#39; WHERE val &lt;= &#39;||size[3]||&#39;;&#39;;
<a name="l00154"></a>00154 EXECUTE &#39;TRUNCATE temptable&#39;||increment%2||&#39;;&#39;;
<a name="l00155"></a>00155 END IF;
<a name="l00156"></a>00156
<a name="l00157"></a>00157
<a name="l00158"></a>00158 ELSIF((quantile_size - last_count) &gt; 1) THEN
<a name="l00159"></a>00159 <span class="comment">/*</span>
<a name="l00160"></a>00160 <span class="comment"> If current COUNT is less than &#39;size[2]&#39; we will increse the value of &#39;size[2]&#39;</span>
<a name="l00161"></a>00161 <span class="comment"> in binarry search fashion. And then update lower limit to our search the max value observed in this round</span>
<a name="l00162"></a>00162 <span class="comment"> */</span>
<a name="l00163"></a>00163 size[1] = last_values[3];
<a name="l00164"></a>00164 size[2] = (last_values[3]+size[3])/2.0;
<a name="l00165"></a>00165
<a name="l00166"></a>00166 --remove all rows that are smaller than new min
<a name="l00167"></a>00167 IF(increment = 0) THEN
<a name="l00168"></a>00168 --add a small offset to ensure the value that is equal to size[1] is NOT kept
<a name="l00169"></a>00169 EXECUTE &#39;INSERT INTO temptable&#39;||(increment+1)%2||&#39; SELECT &#39;||col_name||&#39; FROM &#39;||table_name||&#39; WHERE &#39;||col_name||&#39; &gt; &#39;||size[1]||&#39;+1e-10;&#39;;
<a name="l00170"></a>00170 ELSE
<a name="l00171"></a>00171 EXECUTE &#39;INSERT INTO temptable&#39;||(increment+1)%2||&#39; SELECT val FROM temptable&#39;||increment%2||&#39; WHERE val &gt; &#39;||size[1]||&#39;+1e-10;&#39;;
<a name="l00172"></a>00172 EXECUTE &#39;TRUNCATE temptable&#39;||increment%2||&#39;;&#39;;
<a name="l00173"></a>00173 END IF;
<a name="l00174"></a>00174 rows_removed = last_count;
<a name="l00175"></a>00175
<a name="l00176"></a>00176 ELSE
<a name="l00177"></a>00177 <span class="comment">/*</span>
<a name="l00178"></a>00178 <span class="comment"> EXIT since we are closer than 1 element away from the quantile size</span>
<a name="l00179"></a>00179 <span class="comment"> */</span>
<a name="l00180"></a>00180 IF((quantile_size - last_count) &lt; 0)THEN
<a name="l00181"></a>00181 size[2] = last_values[3];
<a name="l00182"></a>00182 END IF;
<a name="l00183"></a>00183 EXIT;
<a name="l00184"></a>00184 END IF;
<a name="l00185"></a>00185 increment = increment+1;
<a name="l00186"></a>00186 curr_old = last_count;
<a name="l00187"></a>00187 END LOOP;
<a name="l00188"></a>00188
<a name="l00189"></a>00189 <span class="comment">/*</span>
<a name="l00190"></a>00190 <span class="comment"> At this point we terminated the binary search but we do not know what the reason why no progress could be made</span>
<a name="l00191"></a>00191 <span class="comment"> following is the code that determines what is the reason for the termination, and finds the exact solution depending on the reason</span>
<a name="l00192"></a>00192 <span class="comment"> */</span>
<a name="l00193"></a>00193 EXECUTE &#39;SELECT MAX(&#39;||col_name||&#39;),COUNT(*) FROM &#39;||table_name||&#39; WHERE &#39;||col_name||&#39; &lt; &#39;||size[2]||&#39;;&#39; INTO last_value1, last_count1;
<a name="l00194"></a>00194
<a name="l00195"></a>00195 IF(last_count1 &gt;= quantile_size) THEN
<a name="l00196"></a>00196 RETURN last_value1;
<a name="l00197"></a>00197 END IF;
<a name="l00198"></a>00198
<a name="l00199"></a>00199 EXECUTE &#39;SELECT MIN(&#39;||col_name||&#39;),&#39;||full_size||&#39;-COUNT(*)+1 FROM &#39;||table_name||&#39; WHERE &#39;||col_name||&#39; &gt; &#39;||size[2]||&#39;;&#39; INTO last_value2, last_count2;
<a name="l00200"></a>00200
<a name="l00201"></a>00201
<a name="l00202"></a>00202 IF(last_count &gt;= quantile_size) THEN
<a name="l00203"></a>00203 --If the difference is greater than 1 element away, then there are probably many repeated values
<a name="l00204"></a>00204 IF(last_count-quantile_size &gt;= 1) THEN
<a name="l00205"></a>00205 RETURN last_values[3];
<a name="l00206"></a>00206 END IF;
<a name="l00207"></a>00207 RETURN last_values[3]*(quantile_size-last_count1)/(last_count-last_count1)+last_value1*(last_count-quantile_size)/(last_count-last_count1);
<a name="l00208"></a>00208 ELSE
<a name="l00209"></a>00209 --If the difference is greater than 1 element away, then there are probably many repeated values
<a name="l00210"></a>00210 IF(quantile_size-last_count &gt; 1) THEN
<a name="l00211"></a>00211 RETURN last_value2;
<a name="l00212"></a>00212 END IF;
<a name="l00213"></a>00213 RETURN last_value2*(quantile_size-last_count)/(last_count2-last_count)+last_values[3]*(last_count2-quantile_size)/(last_count2-last_count);
<a name="l00214"></a>00214 END IF;
<a name="l00215"></a>00215
<a name="l00216"></a>00216 -- Cleanup
<a name="l00217"></a>00217 DROP TABLE IF EXISTS temptable0;
<a name="l00218"></a>00218 DROP TABLE IF EXISTS temptable1;
<a name="l00219"></a>00219
<a name="l00220"></a>00220 end
<a name="l00221"></a>00221 $$ LANGUAGE plpgsql;
<a name="l00222"></a>00222 <span class="comment"></span>
<a name="l00223"></a>00223 <span class="comment">/**</span>
<a name="l00224"></a>00224 <span class="comment"> * @brief Computes quantile</span>
<a name="l00225"></a>00225 <span class="comment"> *</span>
<a name="l00226"></a>00226 <span class="comment"> * @param table_name name of the table from which quantile is to be taken</span>
<a name="l00227"></a>00227 <span class="comment"> * @param col_name name of the column that is to be used for quantile calculation</span>
<a name="l00228"></a>00228 <span class="comment"> * @param quantile desired quantile value \f$ \in (0,1) \f$</span>
<a name="l00229"></a>00229 <span class="comment"> * @returns The quantile value</span>
<a name="l00230"></a>00230 <span class="comment"> *</span>
<a name="l00231"></a>00231 <span class="comment"> * This function computes the specified quantile value. It reads the name of the</span>
<a name="l00232"></a>00232 <span class="comment"> * table, the specific column, and computes the quantile value based on the</span>
<a name="l00233"></a>00233 <span class="comment"> * fraction specified as the third argument.</span>
<a name="l00234"></a>00234 <span class="comment"> */</span>
<a name="l00235"></a><a class="code" href="quantile_8sql__in.html#a6955e44659a0817803ab7a11a9a7e8a5">00235</a> CREATE OR REPLACE FUNCTION MADLIB_SCHEMA.<a class="code" href="quantile_8sql__in.html#a6955e44659a0817803ab7a11a9a7e8a5" title="Computes quantile.">quantile</a>(table_name TEXT, col_name TEXT, <a class="code" href="quantile_8sql__in.html#a6955e44659a0817803ab7a11a9a7e8a5" title="Computes quantile.">quantile</a> FLOAT) RETURNS FLOAT AS $$
<a name="l00236"></a>00236 declare
<a name="l00237"></a>00237 size FLOAT;
<a name="l00238"></a>00238 result FLOAT[];
<a name="l00239"></a>00239 res FLOAT;
<a name="l00240"></a>00240 begin
<a name="l00241"></a>00241 -- check for bad input
<a name="l00242"></a>00242 IF(<a class="code" href="quantile_8sql__in.html#a6955e44659a0817803ab7a11a9a7e8a5" title="Computes quantile.">quantile</a> &lt; 0) OR (<a class="code" href="quantile_8sql__in.html#a6955e44659a0817803ab7a11a9a7e8a5" title="Computes quantile.">quantile</a> &gt;= 1) THEN
<a name="l00243"></a>00243 RAISE EXCEPTION &#39;Quantile should be between 0 and 0.99&#39;;
<a name="l00244"></a>00244 END IF;
<a name="l00245"></a>00245
<a name="l00246"></a>00246 EXECUTE &#39;SELECT COUNT(*)*&#39;||<a class="code" href="quantile_8sql__in.html#a6955e44659a0817803ab7a11a9a7e8a5" title="Computes quantile.">quantile</a>||&#39; FROM &#39;||table_name||&#39; &#39; INTO size;
<a name="l00247"></a>00247 EXECUTE &#39;SELECT ARRAY(SELECT &#39;||col_name||&#39; FROM (SELECT &#39;||col_name||&#39; FROM &#39;||table_name||&#39; ORDER BY &#39;||col_name||&#39; OFFSET &#39;||floor(size)||&#39;-1 LIMIT 2) AS g)&#39; INTO result;
<a name="l00248"></a>00248 EXECUTE &#39;SELECT &#39;||result[2]||&#39;*(&#39;||size||&#39;%1)+&#39;||result[1]||&#39;*(1-&#39;||size||&#39;%1)&#39; INTO res;
<a name="l00249"></a>00249 return res;
<a name="l00250"></a>00250 end
<a name="l00251"></a>00251 $$ LANGUAGE plpgsql;
</pre></div></div>
</div>
<div id="nav-path" class="navpath">
<ul>
<li class="navelem"><a class="el" href="quantile_8sql__in.html">quantile.sql_in</a> </li>
<!-- window showing the filter options -->
<div id="MSearchSelectWindow"
onmouseover="return searchBox.OnSearchSelectShow()"
onmouseout="return searchBox.OnSearchSelectHide()"
onkeydown="return searchBox.OnSearchSelectKey(event)">
<a class="SelectItem" href="javascript:void(0)" onclick="searchBox.OnSelectItem(0)"><span class="SelectionMark">&#160;</span>All</a><a class="SelectItem" href="javascript:void(0)" onclick="searchBox.OnSelectItem(1)"><span class="SelectionMark">&#160;</span>Files</a><a class="SelectItem" href="javascript:void(0)" onclick="searchBox.OnSelectItem(2)"><span class="SelectionMark">&#160;</span>Functions</a></div>
<!-- iframe showing the search results (closed by default) -->
<div id="MSearchResultsWindow">
<iframe src="javascript:void(0)" frameborder="0"
name="MSearchResults" id="MSearchResults">
</iframe>
</div>
<li class="footer">Generated on Tue Apr 2 2013 14:57:03 for MADlib by
<a href="http://www.doxygen.org/index.html">
<img class="footer" src="doxygen.png" alt="doxygen"/></a> 1.7.5.1 </li>
</ul>
</div>
</body>
</html>