blob: 72bf4839077cb61c7db3c23c025c70c0d024f5a0 [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"/>
<meta http-equiv="X-UA-Compatible" content="IE=9"/>
<meta name="generator" content="Doxygen 1.8.4"/>
<title>MADlib: quantile.sql_in Source File</title>
<link href="tabs.css" rel="stylesheet" type="text/css"/>
<script type="text/javascript" src="jquery.js"></script>
<script type="text/javascript" src="dynsections.js"></script>
<link href="navtree.css" rel="stylesheet" type="text/css"/>
<script type="text/javascript" src="resize.js"></script>
<script type="text/javascript" src="navtree.js"></script>
<script type="text/javascript">
$(document).ready(initResizable);
$(window).load(resizeHeight);
</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 type="text/x-mathjax-config">
MathJax.Hub.Config({
extensions: ["tex2jax.js", "TeX/AMSmath.js", "TeX/AMSsymbols.js"],
jax: ["input/TeX","output/HTML-CSS"],
});
</script><script src="../mathjax/MathJax.js"></script>
<link href="doxygen.css" rel="stylesheet" type="text/css" />
</head>
<body>
<div id="top"><!-- do not remove this div, it is closed by doxygen! -->
<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">1.1</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>
<!-- end header part -->
<!-- Generated by Doxygen 1.8.4 -->
<script type="text/javascript">
var searchBox = new SearchBox("searchBox", "search",false,'Search');
</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><!-- top -->
<div id="side-nav" class="ui-resizable side-nav-resizable">
<div id="nav-tree">
<div id="nav-tree-contents">
<div id="nav-sync" class="sync"></div>
</div>
</div>
<div id="splitbar" style="-moz-user-select:none;"
class="ui-resizable-handle">
</div>
</div>
<script type="text/javascript">
$(document).ready(function(){initNavTree('quantile_8sql__in_source.html','');});
</script>
<div id="doc-content">
<!-- 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><a class="SelectItem" href="javascript:void(0)" onclick="searchBox.OnSelectItem(3)"><span class="SelectionMark">&#160;</span>Groups</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>
<div class="header">
<div class="headertitle">
<div class="title">quantile.sql_in</div> </div>
</div><!--header-->
<div class="contents">
<a href="quantile_8sql__in.html">Go to the documentation of this file.</a><div class="fragment"><div class="line"><a name="l00001"></a><span class="lineno"> 1</span>&#160;<span class="comment">/* ----------------------------------------------------------------------- */</span><span class="comment">/**</span></div>
<div class="line"><a name="l00002"></a><span class="lineno"> 2</span>&#160;<span class="comment"> *</span></div>
<div class="line"><a name="l00003"></a><span class="lineno"> 3</span>&#160;<span class="comment"> * @file quantile.sql_in</span></div>
<div class="line"><a name="l00004"></a><span class="lineno"> 4</span>&#160;<span class="comment"> *</span></div>
<div class="line"><a name="l00005"></a><span class="lineno"> 5</span>&#160;<span class="comment"> * @brief SQL function for Quantile</span></div>
<div class="line"><a name="l00006"></a><span class="lineno"> 6</span>&#160;<span class="comment"> * @date January 2011</span></div>
<div class="line"><a name="l00007"></a><span class="lineno"> 7</span>&#160;<span class="comment"> *</span></div>
<div class="line"><a name="l00008"></a><span class="lineno"> 8</span>&#160;<span class="comment"> * @sa For a brief introduction to quantiles, see the module</span></div>
<div class="line"><a name="l00009"></a><span class="lineno"> 9</span>&#160;<span class="comment"> * description \ref grp_quantile.</span></div>
<div class="line"><a name="l00010"></a><span class="lineno"> 10</span>&#160;<span class="comment"> *</span></div>
<div class="line"><a name="l00011"></a><span class="lineno"> 11</span>&#160;<span class="comment"> */</span><span class="comment">/* ----------------------------------------------------------------------- */</span></div>
<div class="line"><a name="l00012"></a><span class="lineno"> 12</span>&#160;<span class="comment"></span></div>
<div class="line"><a name="l00013"></a><span class="lineno"> 13</span>&#160;<span class="comment">/**</span></div>
<div class="line"><a name="l00014"></a><span class="lineno"> 14</span>&#160;<span class="comment">@addtogroup grp_quantile</span></div>
<div class="line"><a name="l00015"></a><span class="lineno"> 15</span>&#160;<span class="comment"></span></div>
<div class="line"><a name="l00016"></a><span class="lineno"> 16</span>&#160;<span class="comment">\warning &lt;em&gt; This MADlib method is still in early stage development. There may be some </span></div>
<div class="line"><a name="l00017"></a><span class="lineno"> 17</span>&#160;<span class="comment">issues that will be addressed in a future version. Interface and implementation</span></div>
<div class="line"><a name="l00018"></a><span class="lineno"> 18</span>&#160;<span class="comment">is subject to change. &lt;/em&gt;</span></div>
<div class="line"><a name="l00019"></a><span class="lineno"> 19</span>&#160;<span class="comment"></span></div>
<div class="line"><a name="l00020"></a><span class="lineno"> 20</span>&#160;<span class="comment">@about</span></div>
<div class="line"><a name="l00021"></a><span class="lineno"> 21</span>&#160;<span class="comment">This function computes the specified quantile value. It reads the name of the</span></div>
<div class="line"><a name="l00022"></a><span class="lineno"> 22</span>&#160;<span class="comment">table, the specific column, and computes the quantile value based on the</span></div>
<div class="line"><a name="l00023"></a><span class="lineno"> 23</span>&#160;<span class="comment">fraction specified as the third argument.</span></div>
<div class="line"><a name="l00024"></a><span class="lineno"> 24</span>&#160;<span class="comment"></span></div>
<div class="line"><a name="l00025"></a><span class="lineno"> 25</span>&#160;<span class="comment">For an implementation of quantile using sketches, check out the cmsketch_centile()</span></div>
<div class="line"><a name="l00026"></a><span class="lineno"> 26</span>&#160;<span class="comment">aggregate in the \ref grp_countmin module.</span></div>
<div class="line"><a name="l00027"></a><span class="lineno"> 27</span>&#160;<span class="comment"></span></div>
<div class="line"><a name="l00028"></a><span class="lineno"> 28</span>&#160;<span class="comment">@implementation</span></div>
<div class="line"><a name="l00029"></a><span class="lineno"> 29</span>&#160;<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></div>
<div class="line"><a name="l00030"></a><span class="lineno"> 30</span>&#160;<span class="comment">consider using &lt;tt&gt;quantile_big&lt;/tt&gt; instead.</span></div>
<div class="line"><a name="l00031"></a><span class="lineno"> 31</span>&#160;<span class="comment"></span></div>
<div class="line"><a name="l00032"></a><span class="lineno"> 32</span>&#160;<span class="comment">@usage</span></div>
<div class="line"><a name="l00033"></a><span class="lineno"> 33</span>&#160;<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></div>
<div class="line"><a name="l00034"></a><span class="lineno"> 34</span>&#160;<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></div>
<div class="line"><a name="l00035"></a><span class="lineno"> 35</span>&#160;<span class="comment"></span></div>
<div class="line"><a name="l00036"></a><span class="lineno"> 36</span>&#160;<span class="comment">@examp</span></div>
<div class="line"><a name="l00037"></a><span class="lineno"> 37</span>&#160;<span class="comment"></span></div>
<div class="line"><a name="l00038"></a><span class="lineno"> 38</span>&#160;<span class="comment">-# Prepare some input:</span></div>
<div class="line"><a name="l00039"></a><span class="lineno"> 39</span>&#160;<span class="comment">\verbatim</span></div>
<div class="line"><a name="l00040"></a><span class="lineno"> 40</span>&#160;<span class="comment">sql&gt; CREATE TABLE tab1 AS SELECT generate_series( 1,1000) as col1;</span></div>
<div class="line"><a name="l00041"></a><span class="lineno"> 41</span>&#160;<span class="comment">\endverbatim</span></div>
<div class="line"><a name="l00042"></a><span class="lineno"> 42</span>&#160;<span class="comment">-# Run the quantile() function:\n</span></div>
<div class="line"><a name="l00043"></a><span class="lineno"> 43</span>&#160;<span class="comment">\verbatim</span></div>
<div class="line"><a name="l00044"></a><span class="lineno"> 44</span>&#160;<span class="comment">sql&gt; SELECT quantile( &#39;tab1&#39;, &#39;col1&#39;, .3);</span></div>
<div class="line"><a name="l00045"></a><span class="lineno"> 45</span>&#160;<span class="comment"></span></div>
<div class="line"><a name="l00046"></a><span class="lineno"> 46</span>&#160;<span class="comment"> quantile </span></div>
<div class="line"><a name="l00047"></a><span class="lineno"> 47</span>&#160;<span class="comment">--------------</span></div>
<div class="line"><a name="l00048"></a><span class="lineno"> 48</span>&#160;<span class="comment"> 301.48046875</span></div>
<div class="line"><a name="l00049"></a><span class="lineno"> 49</span>&#160;<span class="comment">(1 row)</span></div>
<div class="line"><a name="l00050"></a><span class="lineno"> 50</span>&#160;<span class="comment">\endverbatim</span></div>
<div class="line"><a name="l00051"></a><span class="lineno"> 51</span>&#160;<span class="comment"></span></div>
<div class="line"><a name="l00052"></a><span class="lineno"> 52</span>&#160;<span class="comment">@sa File quantile.sql_in documenting the SQL function.\n\n</span></div>
<div class="line"><a name="l00053"></a><span class="lineno"> 53</span>&#160;<span class="comment">Module grp_countmin for an approximate quantile implementation.</span></div>
<div class="line"><a name="l00054"></a><span class="lineno"> 54</span>&#160;<span class="comment">*/</span></div>
<div class="line"><a name="l00055"></a><span class="lineno"> 55</span>&#160;</div>
<div class="line"><a name="l00056"></a><span class="lineno"> 56</span>&#160;<span class="comment"></span></div>
<div class="line"><a name="l00057"></a><span class="lineno"> 57</span>&#160;<span class="comment">/**</span></div>
<div class="line"><a name="l00058"></a><span class="lineno"> 58</span>&#160;<span class="comment"> * @brief Computes quantile</span></div>
<div class="line"><a name="l00059"></a><span class="lineno"> 59</span>&#160;<span class="comment"> *</span></div>
<div class="line"><a name="l00060"></a><span class="lineno"> 60</span>&#160;<span class="comment"> * @param table_name name of the table from which quantile is to be taken</span></div>
<div class="line"><a name="l00061"></a><span class="lineno"> 61</span>&#160;<span class="comment"> * @param col_name name of the column that is to be used for quantile calculation</span></div>
<div class="line"><a name="l00062"></a><span class="lineno"> 62</span>&#160;<span class="comment"> * @param quantile desired quantile value \f$ \in (0,1) \f$</span></div>
<div class="line"><a name="l00063"></a><span class="lineno"> 63</span>&#160;<span class="comment"> * @returns The quantile value</span></div>
<div class="line"><a name="l00064"></a><span class="lineno"> 64</span>&#160;<span class="comment"> *</span></div>
<div class="line"><a name="l00065"></a><span class="lineno"> 65</span>&#160;<span class="comment"> * This function computes the specified quantile value. It reads the name of the</span></div>
<div class="line"><a name="l00066"></a><span class="lineno"> 66</span>&#160;<span class="comment"> * table, the specific column, and computes the quantile value based on the</span></div>
<div class="line"><a name="l00067"></a><span class="lineno"> 67</span>&#160;<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></div>
<div class="line"><a name="l00068"></a><span class="lineno"> 68</span>&#160;<span class="comment"> */</span></div>
<div class="line"><a name="l00069"></a><span class="lineno"><a class="code" href="quantile_8sql__in.html#a154435ddf6200110013dc05b1a6207fe"> 69</a></span>&#160;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 $$</div>
<div class="line"><a name="l00070"></a><span class="lineno"> 70</span>&#160;declare</div>
<div class="line"><a name="l00071"></a><span class="lineno"> 71</span>&#160; size FLOAT[];</div>
<div class="line"><a name="l00072"></a><span class="lineno"> 72</span>&#160; count BIGINT;</div>
<div class="line"><a name="l00073"></a><span class="lineno"> 73</span>&#160; increment INT := 0;</div>
<div class="line"><a name="l00074"></a><span class="lineno"> 74</span>&#160; curr_old BIGINT;</div>
<div class="line"><a name="l00075"></a><span class="lineno"> 75</span>&#160; last_values FLOAT[];</div>
<div class="line"><a name="l00076"></a><span class="lineno"> 76</span>&#160; last_count BIGINT;</div>
<div class="line"><a name="l00077"></a><span class="lineno"> 77</span>&#160; last_value1 FLOAT;</div>
<div class="line"><a name="l00078"></a><span class="lineno"> 78</span>&#160; last_count1 BIGINT;</div>
<div class="line"><a name="l00079"></a><span class="lineno"> 79</span>&#160; last_value2 FLOAT;</div>
<div class="line"><a name="l00080"></a><span class="lineno"> 80</span>&#160; last_count2 BIGINT;</div>
<div class="line"><a name="l00081"></a><span class="lineno"> 81</span>&#160; quantile_size BIGINT;</div>
<div class="line"><a name="l00082"></a><span class="lineno"> 82</span>&#160; full_size BIGINT;</div>
<div class="line"><a name="l00083"></a><span class="lineno"> 83</span>&#160; rows_removed BIGINT := 0;</div>
<div class="line"><a name="l00084"></a><span class="lineno"> 84</span>&#160;Begin</div>
<div class="line"><a name="l00085"></a><span class="lineno"> 85</span>&#160; <span class="comment">/*</span></div>
<div class="line"><a name="l00086"></a><span class="lineno"> 86</span>&#160;<span class="comment"> This portion computes basic statistics on the table, finding:</span></div>
<div class="line"><a name="l00087"></a><span class="lineno"> 87</span>&#160;<span class="comment"> MIN value</span></div>
<div class="line"><a name="l00088"></a><span class="lineno"> 88</span>&#160;<span class="comment"> AVG value</span></div>
<div class="line"><a name="l00089"></a><span class="lineno"> 89</span>&#160;<span class="comment"> MAX value</span></div>
<div class="line"><a name="l00090"></a><span class="lineno"> 90</span>&#160;<span class="comment"> COOUNT of the elemens</span></div>
<div class="line"><a name="l00091"></a><span class="lineno"> 91</span>&#160;<span class="comment"> Which at stored in that order into &#39;size&#39;, count object</span></div>
<div class="line"><a name="l00092"></a><span class="lineno"> 92</span>&#160;<span class="comment"> &#39;quantile_size&#39; is computed in terms of element count</span></div>
<div class="line"><a name="l00093"></a><span class="lineno"> 93</span>&#160;<span class="comment"> */</span></div>
<div class="line"><a name="l00094"></a><span class="lineno"> 94</span>&#160; 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;</div>
<div class="line"><a name="l00095"></a><span class="lineno"> 95</span>&#160; quantile_size = (count*<a class="code" href="quantile_8sql__in.html#a6955e44659a0817803ab7a11a9a7e8a5" title="Computes quantile. ">quantile</a>)::BIGINT;</div>
<div class="line"><a name="l00096"></a><span class="lineno"> 96</span>&#160; full_size = count;</div>
<div class="line"><a name="l00097"></a><span class="lineno"> 97</span>&#160;</div>
<div class="line"><a name="l00098"></a><span class="lineno"> 98</span>&#160; -- check <span class="keywordflow">for</span> bad input</div>
<div class="line"><a name="l00099"></a><span class="lineno"> 99</span>&#160; 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</div>
<div class="line"><a name="l00100"></a><span class="lineno"> 100</span>&#160; RAISE EXCEPTION &#39;Quantile should be between 0 and 0.99&#39;;</div>
<div class="line"><a name="l00101"></a><span class="lineno"> 101</span>&#160; ELSIF(<a class="code" href="quantile_8sql__in.html#a6955e44659a0817803ab7a11a9a7e8a5" title="Computes quantile. ">quantile</a> = 0) THEN</div>
<div class="line"><a name="l00102"></a><span class="lineno"> 102</span>&#160; RETURN size[1];</div>
<div class="line"><a name="l00103"></a><span class="lineno"> 103</span>&#160; END IF;</div>
<div class="line"><a name="l00104"></a><span class="lineno"> 104</span>&#160;</div>
<div class="line"><a name="l00105"></a><span class="lineno"> 105</span>&#160; -- create some temp tables to use as swap</div>
<div class="line"><a name="l00106"></a><span class="lineno"> 106</span>&#160; DROP TABLE IF EXISTS temptable0;</div>
<div class="line"><a name="l00107"></a><span class="lineno"> 107</span>&#160; CREATE TEMP TABLE temptable0(val FLOAT);</div>
<div class="line"><a name="l00108"></a><span class="lineno"> 108</span>&#160;</div>
<div class="line"><a name="l00109"></a><span class="lineno"> 109</span>&#160; DROP TABLE IF EXISTS temptable1;</div>
<div class="line"><a name="l00110"></a><span class="lineno"> 110</span>&#160; CREATE TEMP TABLE temptable1(val FLOAT);</div>
<div class="line"><a name="l00111"></a><span class="lineno"> 111</span>&#160;</div>
<div class="line"><a name="l00112"></a><span class="lineno"> 112</span>&#160;</div>
<div class="line"><a name="l00113"></a><span class="lineno"> 113</span>&#160; <span class="comment">/*</span></div>
<div class="line"><a name="l00114"></a><span class="lineno"> 114</span>&#160;<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></div>
<div class="line"><a name="l00115"></a><span class="lineno"> 115</span>&#160;<span class="comment"> quantile size.</span></div>
<div class="line"><a name="l00116"></a><span class="lineno"> 116</span>&#160;<span class="comment"></span></div>
<div class="line"><a name="l00117"></a><span class="lineno"> 117</span>&#160;<span class="comment"> In each itteration for a given value &#39;size[2]&#39; following are computed:</span></div>
<div class="line"><a name="l00118"></a><span class="lineno"> 118</span>&#160;<span class="comment"> MIN value less than or equal to &#39;size[2]&#39;</span></div>
<div class="line"><a name="l00119"></a><span class="lineno"> 119</span>&#160;<span class="comment"> AVERAGE value less than or equal to &#39;size[2]&#39;</span></div>
<div class="line"><a name="l00120"></a><span class="lineno"> 120</span>&#160;<span class="comment"> MAX value less than or equal to &#39;size[2]&#39;</span></div>
<div class="line"><a name="l00121"></a><span class="lineno"> 121</span>&#160;<span class="comment"> COUNT of the values less than or equal to &#39;size[2]&#39;</span></div>
<div class="line"><a name="l00122"></a><span class="lineno"> 122</span>&#160;<span class="comment"> This results are stored into &#39;last_values&#39;, last_count in that order</span></div>
<div class="line"><a name="l00123"></a><span class="lineno"> 123</span>&#160;<span class="comment"> */</span></div>
<div class="line"><a name="l00124"></a><span class="lineno"> 124</span>&#160; LOOP</div>
<div class="line"><a name="l00125"></a><span class="lineno"> 125</span>&#160; IF(increment = 0) THEN</div>
<div class="line"><a name="l00126"></a><span class="lineno"> 126</span>&#160; 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;</div>
<div class="line"><a name="l00127"></a><span class="lineno"> 127</span>&#160; ELSE</div>
<div class="line"><a name="l00128"></a><span class="lineno"> 128</span>&#160; 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;</div>
<div class="line"><a name="l00129"></a><span class="lineno"> 129</span>&#160; END IF;</div>
<div class="line"><a name="l00130"></a><span class="lineno"> 130</span>&#160; last_count = last_count + rows_removed;</div>
<div class="line"><a name="l00131"></a><span class="lineno"> 131</span>&#160;</div>
<div class="line"><a name="l00132"></a><span class="lineno"> 132</span>&#160;</div>
<div class="line"><a name="l00133"></a><span class="lineno"> 133</span>&#160; IF(last_count=rows_removed) THEN</div>
<div class="line"><a name="l00134"></a><span class="lineno"> 134</span>&#160; <span class="comment">/*</span></div>
<div class="line"><a name="l00135"></a><span class="lineno"> 135</span>&#160;<span class="comment"> If there are no more rows left, we exit.</span></div>
<div class="line"><a name="l00136"></a><span class="lineno"> 136</span>&#160;<span class="comment"> */</span></div>
<div class="line"><a name="l00137"></a><span class="lineno"> 137</span>&#160; EXIT;</div>
<div class="line"><a name="l00138"></a><span class="lineno"> 138</span>&#160;</div>
<div class="line"><a name="l00139"></a><span class="lineno"> 139</span>&#160; ELSIF((increment &gt; 0)AND(curr_old = last_count)) THEN</div>
<div class="line"><a name="l00140"></a><span class="lineno"> 140</span>&#160; <span class="comment">/*</span></div>
<div class="line"><a name="l00141"></a><span class="lineno"> 141</span>&#160;<span class="comment"> We will exit the loop if there was not change in the count from previous itteration</span></div>
<div class="line"><a name="l00142"></a><span class="lineno"> 142</span>&#160;<span class="comment"> which mean that process will make no further progress.</span></div>
<div class="line"><a name="l00143"></a><span class="lineno"> 143</span>&#160;<span class="comment"> */</span></div>
<div class="line"><a name="l00144"></a><span class="lineno"> 144</span>&#160; EXIT;</div>
<div class="line"><a name="l00145"></a><span class="lineno"> 145</span>&#160; ELSIF((last_count - quantile_size) &gt; 1) THEN</div>
<div class="line"><a name="l00146"></a><span class="lineno"> 146</span>&#160; <span class="comment">/*</span></div>
<div class="line"><a name="l00147"></a><span class="lineno"> 147</span>&#160;<span class="comment"> If current COUNT is greater than &#39;size[2]&#39; we will reduce the value of &#39;size[2]&#39;</span></div>
<div class="line"><a name="l00148"></a><span class="lineno"> 148</span>&#160;<span class="comment"> in binarry search fashion. And then update upper limit to our search the max value observed in this round</span></div>
<div class="line"><a name="l00149"></a><span class="lineno"> 149</span>&#160;<span class="comment"> */</span></div>
<div class="line"><a name="l00150"></a><span class="lineno"> 150</span>&#160; size[2] = (last_values[3]+size[1])/2.0;</div>
<div class="line"><a name="l00151"></a><span class="lineno"> 151</span>&#160; size[3] = last_values[3];</div>
<div class="line"><a name="l00152"></a><span class="lineno"> 152</span>&#160;</div>
<div class="line"><a name="l00153"></a><span class="lineno"> 153</span>&#160; --remove all rows that are larger than new max</div>
<div class="line"><a name="l00154"></a><span class="lineno"> 154</span>&#160; IF(increment = 0) THEN</div>
<div class="line"><a name="l00155"></a><span class="lineno"> 155</span>&#160; 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;;</div>
<div class="line"><a name="l00156"></a><span class="lineno"> 156</span>&#160; ELSE</div>
<div class="line"><a name="l00157"></a><span class="lineno"> 157</span>&#160; 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;;</div>
<div class="line"><a name="l00158"></a><span class="lineno"> 158</span>&#160; EXECUTE &#39;TRUNCATE temptable&#39;||increment%2||&#39;;&#39;;</div>
<div class="line"><a name="l00159"></a><span class="lineno"> 159</span>&#160; END IF;</div>
<div class="line"><a name="l00160"></a><span class="lineno"> 160</span>&#160;</div>
<div class="line"><a name="l00161"></a><span class="lineno"> 161</span>&#160;</div>
<div class="line"><a name="l00162"></a><span class="lineno"> 162</span>&#160; ELSIF((quantile_size - last_count) &gt; 1) THEN</div>
<div class="line"><a name="l00163"></a><span class="lineno"> 163</span>&#160; <span class="comment">/*</span></div>
<div class="line"><a name="l00164"></a><span class="lineno"> 164</span>&#160;<span class="comment"> If current COUNT is less than &#39;size[2]&#39; we will increse the value of &#39;size[2]&#39;</span></div>
<div class="line"><a name="l00165"></a><span class="lineno"> 165</span>&#160;<span class="comment"> in binarry search fashion. And then update lower limit to our search the max value observed in this round</span></div>
<div class="line"><a name="l00166"></a><span class="lineno"> 166</span>&#160;<span class="comment"> */</span></div>
<div class="line"><a name="l00167"></a><span class="lineno"> 167</span>&#160; size[1] = last_values[3];</div>
<div class="line"><a name="l00168"></a><span class="lineno"> 168</span>&#160; size[2] = (last_values[3]+size[3])/2.0;</div>
<div class="line"><a name="l00169"></a><span class="lineno"> 169</span>&#160;</div>
<div class="line"><a name="l00170"></a><span class="lineno"> 170</span>&#160; --remove all rows that are smaller than new min</div>
<div class="line"><a name="l00171"></a><span class="lineno"> 171</span>&#160; IF(increment = 0) THEN</div>
<div class="line"><a name="l00172"></a><span class="lineno"> 172</span>&#160; --add a small offset to ensure the value that is equal to size[1] is NOT kept</div>
<div class="line"><a name="l00173"></a><span class="lineno"> 173</span>&#160; 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;;</div>
<div class="line"><a name="l00174"></a><span class="lineno"> 174</span>&#160; ELSE</div>
<div class="line"><a name="l00175"></a><span class="lineno"> 175</span>&#160; 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;;</div>
<div class="line"><a name="l00176"></a><span class="lineno"> 176</span>&#160; EXECUTE &#39;TRUNCATE temptable&#39;||increment%2||&#39;;&#39;;</div>
<div class="line"><a name="l00177"></a><span class="lineno"> 177</span>&#160; END IF;</div>
<div class="line"><a name="l00178"></a><span class="lineno"> 178</span>&#160; rows_removed = last_count;</div>
<div class="line"><a name="l00179"></a><span class="lineno"> 179</span>&#160;</div>
<div class="line"><a name="l00180"></a><span class="lineno"> 180</span>&#160; ELSE</div>
<div class="line"><a name="l00181"></a><span class="lineno"> 181</span>&#160; <span class="comment">/*</span></div>
<div class="line"><a name="l00182"></a><span class="lineno"> 182</span>&#160;<span class="comment"> EXIT since we are closer than 1 element away from the quantile size</span></div>
<div class="line"><a name="l00183"></a><span class="lineno"> 183</span>&#160;<span class="comment"> */</span></div>
<div class="line"><a name="l00184"></a><span class="lineno"> 184</span>&#160; IF((quantile_size - last_count) &lt; 0)THEN</div>
<div class="line"><a name="l00185"></a><span class="lineno"> 185</span>&#160; size[2] = last_values[3];</div>
<div class="line"><a name="l00186"></a><span class="lineno"> 186</span>&#160; END IF;</div>
<div class="line"><a name="l00187"></a><span class="lineno"> 187</span>&#160; EXIT;</div>
<div class="line"><a name="l00188"></a><span class="lineno"> 188</span>&#160; END IF;</div>
<div class="line"><a name="l00189"></a><span class="lineno"> 189</span>&#160; increment = increment+1;</div>
<div class="line"><a name="l00190"></a><span class="lineno"> 190</span>&#160; curr_old = last_count;</div>
<div class="line"><a name="l00191"></a><span class="lineno"> 191</span>&#160; END LOOP;</div>
<div class="line"><a name="l00192"></a><span class="lineno"> 192</span>&#160;</div>
<div class="line"><a name="l00193"></a><span class="lineno"> 193</span>&#160; <span class="comment">/*</span></div>
<div class="line"><a name="l00194"></a><span class="lineno"> 194</span>&#160;<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></div>
<div class="line"><a name="l00195"></a><span class="lineno"> 195</span>&#160;<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></div>
<div class="line"><a name="l00196"></a><span class="lineno"> 196</span>&#160;<span class="comment"> */</span></div>
<div class="line"><a name="l00197"></a><span class="lineno"> 197</span>&#160; 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;</div>
<div class="line"><a name="l00198"></a><span class="lineno"> 198</span>&#160;</div>
<div class="line"><a name="l00199"></a><span class="lineno"> 199</span>&#160; IF(last_count1 &gt;= quantile_size) THEN</div>
<div class="line"><a name="l00200"></a><span class="lineno"> 200</span>&#160; RETURN last_value1;</div>
<div class="line"><a name="l00201"></a><span class="lineno"> 201</span>&#160; END IF;</div>
<div class="line"><a name="l00202"></a><span class="lineno"> 202</span>&#160;</div>
<div class="line"><a name="l00203"></a><span class="lineno"> 203</span>&#160; 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;</div>
<div class="line"><a name="l00204"></a><span class="lineno"> 204</span>&#160;</div>
<div class="line"><a name="l00205"></a><span class="lineno"> 205</span>&#160;</div>
<div class="line"><a name="l00206"></a><span class="lineno"> 206</span>&#160; IF(last_count &gt;= quantile_size) THEN</div>
<div class="line"><a name="l00207"></a><span class="lineno"> 207</span>&#160; --If the difference is greater than 1 element away, then there are probably many repeated values</div>
<div class="line"><a name="l00208"></a><span class="lineno"> 208</span>&#160; IF(last_count-quantile_size &gt;= 1) THEN</div>
<div class="line"><a name="l00209"></a><span class="lineno"> 209</span>&#160; RETURN last_values[3];</div>
<div class="line"><a name="l00210"></a><span class="lineno"> 210</span>&#160; END IF;</div>
<div class="line"><a name="l00211"></a><span class="lineno"> 211</span>&#160; RETURN last_values[3]*(quantile_size-last_count1)/(last_count-last_count1)+last_value1*(last_count-quantile_size)/(last_count-last_count1);</div>
<div class="line"><a name="l00212"></a><span class="lineno"> 212</span>&#160; ELSE</div>
<div class="line"><a name="l00213"></a><span class="lineno"> 213</span>&#160; --If the difference is greater than 1 element away, then there are probably many repeated values</div>
<div class="line"><a name="l00214"></a><span class="lineno"> 214</span>&#160; IF(quantile_size-last_count &gt; 1) THEN</div>
<div class="line"><a name="l00215"></a><span class="lineno"> 215</span>&#160; RETURN last_value2;</div>
<div class="line"><a name="l00216"></a><span class="lineno"> 216</span>&#160; END IF;</div>
<div class="line"><a name="l00217"></a><span class="lineno"> 217</span>&#160; RETURN last_value2*(quantile_size-last_count)/(last_count2-last_count)+last_values[3]*(last_count2-quantile_size)/(last_count2-last_count);</div>
<div class="line"><a name="l00218"></a><span class="lineno"> 218</span>&#160; END IF;</div>
<div class="line"><a name="l00219"></a><span class="lineno"> 219</span>&#160;</div>
<div class="line"><a name="l00220"></a><span class="lineno"> 220</span>&#160; -- Cleanup</div>
<div class="line"><a name="l00221"></a><span class="lineno"> 221</span>&#160; DROP TABLE IF EXISTS temptable0;</div>
<div class="line"><a name="l00222"></a><span class="lineno"> 222</span>&#160; DROP TABLE IF EXISTS temptable1;</div>
<div class="line"><a name="l00223"></a><span class="lineno"> 223</span>&#160;</div>
<div class="line"><a name="l00224"></a><span class="lineno"> 224</span>&#160;end</div>
<div class="line"><a name="l00225"></a><span class="lineno"> 225</span>&#160;$$ LANGUAGE plpgsql;</div>
<div class="line"><a name="l00226"></a><span class="lineno"> 226</span>&#160;<span class="comment"></span></div>
<div class="line"><a name="l00227"></a><span class="lineno"> 227</span>&#160;<span class="comment">/**</span></div>
<div class="line"><a name="l00228"></a><span class="lineno"> 228</span>&#160;<span class="comment"> * @brief Computes quantile</span></div>
<div class="line"><a name="l00229"></a><span class="lineno"> 229</span>&#160;<span class="comment"> *</span></div>
<div class="line"><a name="l00230"></a><span class="lineno"> 230</span>&#160;<span class="comment"> * @param table_name name of the table from which quantile is to be taken</span></div>
<div class="line"><a name="l00231"></a><span class="lineno"> 231</span>&#160;<span class="comment"> * @param col_name name of the column that is to be used for quantile calculation</span></div>
<div class="line"><a name="l00232"></a><span class="lineno"> 232</span>&#160;<span class="comment"> * @param quantile desired quantile value \f$ \in (0,1) \f$</span></div>
<div class="line"><a name="l00233"></a><span class="lineno"> 233</span>&#160;<span class="comment"> * @returns The quantile value</span></div>
<div class="line"><a name="l00234"></a><span class="lineno"> 234</span>&#160;<span class="comment"> *</span></div>
<div class="line"><a name="l00235"></a><span class="lineno"> 235</span>&#160;<span class="comment"> * This function computes the specified quantile value. It reads the name of the</span></div>
<div class="line"><a name="l00236"></a><span class="lineno"> 236</span>&#160;<span class="comment"> * table, the specific column, and computes the quantile value based on the</span></div>
<div class="line"><a name="l00237"></a><span class="lineno"> 237</span>&#160;<span class="comment"> * fraction specified as the third argument.</span></div>
<div class="line"><a name="l00238"></a><span class="lineno"> 238</span>&#160;<span class="comment"> */</span></div>
<div class="line"><a name="l00239"></a><span class="lineno"><a class="code" href="quantile_8sql__in.html#a6955e44659a0817803ab7a11a9a7e8a5"> 239</a></span>&#160;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 $$</div>
<div class="line"><a name="l00240"></a><span class="lineno"> 240</span>&#160;declare</div>
<div class="line"><a name="l00241"></a><span class="lineno"> 241</span>&#160; size FLOAT;</div>
<div class="line"><a name="l00242"></a><span class="lineno"> 242</span>&#160; result FLOAT[];</div>
<div class="line"><a name="l00243"></a><span class="lineno"> 243</span>&#160; res FLOAT;</div>
<div class="line"><a name="l00244"></a><span class="lineno"> 244</span>&#160;begin</div>
<div class="line"><a name="l00245"></a><span class="lineno"> 245</span>&#160; -- check for bad input</div>
<div class="line"><a name="l00246"></a><span class="lineno"> 246</span>&#160; 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</div>
<div class="line"><a name="l00247"></a><span class="lineno"> 247</span>&#160; RAISE EXCEPTION &#39;Quantile should be between 0 and 0.99&#39;;</div>
<div class="line"><a name="l00248"></a><span class="lineno"> 248</span>&#160; END IF;</div>
<div class="line"><a name="l00249"></a><span class="lineno"> 249</span>&#160;</div>
<div class="line"><a name="l00250"></a><span class="lineno"> 250</span>&#160; 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;</div>
<div class="line"><a name="l00251"></a><span class="lineno"> 251</span>&#160; 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;</div>
<div class="line"><a name="l00252"></a><span class="lineno"> 252</span>&#160; EXECUTE &#39;SELECT &#39;||result[2]||&#39;*(&#39;||size||&#39;%1)+&#39;||result[1]||&#39;*(1-&#39;||size||&#39;%1)&#39; INTO res;</div>
<div class="line"><a name="l00253"></a><span class="lineno"> 253</span>&#160; return res;</div>
<div class="line"><a name="l00254"></a><span class="lineno"> 254</span>&#160;end</div>
<div class="line"><a name="l00255"></a><span class="lineno"> 255</span>&#160;$$ LANGUAGE plpgsql;</div>
</div><!-- fragment --></div><!-- contents -->
</div><!-- doc-content -->
<!-- start footer part -->
<div id="nav-path" class="navpath"><!-- id is needed for treeview function! -->
<ul>
<li class="navelem"><a class="el" href="dir_68267d1309a1af8e8297ef4c3efbcdba.html">src</a></li><li class="navelem"><a class="el" href="dir_efbcf68973d247bbf15f9eecae7f24e3.html">ports</a></li><li class="navelem"><a class="el" href="dir_a4a48839224ef8488facbffa8a397967.html">postgres</a></li><li class="navelem"><a class="el" href="dir_dc596537ad427a4d866006d1a3e1fe29.html">modules</a></li><li class="navelem"><a class="el" href="dir_68045f897311dcb3907add5fe80793a8.html">quantile</a></li><li class="navelem"><a class="el" href="quantile_8sql__in.html">quantile.sql_in</a></li>
<li class="footer">Generated on Wed Aug 21 2013 16:09:52 for MADlib by
<a href="http://www.doxygen.org/index.html">
<img class="footer" src="doxygen.png" alt="doxygen"/></a> 1.8.4 </li>
</ul>
</div>
</body>
</html>