1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323
|
<!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/html; charset=utf-8" />
<title>Examples for using SQL functions — PyGreSQL 5.0 documentation</title>
<link rel="stylesheet" href="../../_static/cloud.css" type="text/css" />
<link rel="stylesheet" href="../../_static/pygments.css" type="text/css" />
<link rel="stylesheet" href="../../_static/pygresql.css" type="text/css" />
<link rel="stylesheet" href="//fonts.googleapis.com/css?family=Noticia+Text|Open+Sans|Droid+Sans+Mono" type="text/css" />
<script type="text/javascript">
var DOCUMENTATION_OPTIONS = {
URL_ROOT: '../../',
VERSION: '5.0.3',
COLLAPSE_INDEX: false,
FILE_SUFFIX: '.html',
HAS_SOURCE: true
};
</script>
<script type="text/javascript" src="../../_static/jquery.js"></script>
<script type="text/javascript" src="../../_static/underscore.js"></script>
<script type="text/javascript" src="../../_static/doctools.js"></script>
<script type="text/javascript" src="../../_static/jquery.cookie.js"></script>
<script type="text/javascript" src="../../_static/cloud.js"></script>
<link rel="shortcut icon" href="../../_static/favicon.ico"/>
<link rel="copyright" title="Copyright" href="../../copyright.html" />
<link rel="top" title="PyGreSQL 5.0 documentation" href="../index.html" />
<link rel="up" title="A PostgreSQL Primer" href="index.html" />
<link rel="next" title="Examples for using the system catalogs" href="syscat.html" />
<link rel="prev" title="Examples for advanced features" href="advanced.html" />
<meta name="viewport" content="width=device-width, initial-scale=1">
</head>
<body role="document">
<div class="pageheader related" role="navigation" aria-label="related navigation">
<ul>
<li><a href="../../index.html">Home</a></li>
<li><a href="../../download/index.html">Download</a></li>
<li><a href="../index.html">Documentation</a></li>
<li><a href="../../community/index.html">Community</a></li>
</ul>
<div class="logo">
<a href="../../index.html">PyGreSQL</a>
</div>
</div>
</div>
<div class="relbar-top">
<div class="related" role="navigation" aria-label="related navigation">
<h3>Navigation</h3>
<ul>
<li class="right" style="margin-right: 10px">
<a href="../../genindex.html" title="General Index"
accesskey="I">index</a></li>
<li class="right" >
<a href="../../py-modindex.html" title="Python Module Index"
>modules</a> </li>
<li class="right" >
<a href="syscat.html" title="Examples for using the system catalogs"
accesskey="N">next</a> </li>
<li class="right" >
<a href="advanced.html" title="Examples for advanced features"
accesskey="P">previous</a> </li>
<li><a href="../index.html">PyGreSQL 5.0 documentation</a> »</li>
<li class="nav-item nav-item-1"><a href="index.html" accesskey="U">A PostgreSQL Primer</a> »</li>
</ul>
</div>
</div>
<div class="document">
<div class="documentwrapper">
<div class="bodywrapper">
<div class="body" role="main">
<div class="section" id="examples-for-using-sql-functions">
<h1>Examples for using SQL functions<a class="headerlink" href="#examples-for-using-sql-functions" title="Permalink to this headline">¶</a></h1>
<p>We assume that you have already created a connection to the PostgreSQL
database, as explained in the <a class="reference internal" href="basic.html"><span class="doc">Basic examples</span></a>:</p>
<div class="highlight-default"><div class="highlight"><pre><span class="gp">>>> </span><span class="kn">from</span> <span class="nn">pg</span> <span class="k">import</span> <span class="n">DB</span>
<span class="gp">>>> </span><span class="n">db</span> <span class="o">=</span> <span class="n">DB</span><span class="p">()</span>
<span class="gp">>>> </span><span class="n">query</span> <span class="o">=</span> <span class="n">db</span><span class="o">.</span><span class="n">query</span>
</pre></div>
</div>
<div class="section" id="creating-sql-functions-on-base-types">
<h2>Creating SQL Functions on Base Types<a class="headerlink" href="#creating-sql-functions-on-base-types" title="Permalink to this headline">¶</a></h2>
<p>A <strong>CREATE FUNCTION</strong> statement lets you create a new function that can be
used in expressions (in SELECT, INSERT, etc.). We will start with functions
that return values of base types.</p>
<p>Let’s create a simple SQL function that takes no arguments and returns 1:</p>
<div class="highlight-default"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">query</span><span class="p">(</span><span class="s">"""CREATE FUNCTION one() RETURNS int4</span>
<span class="gp">... </span><span class="s"> AS 'SELECT 1 as ONE' LANGUAGE SQL"""</span><span class="p">)</span>
</pre></div>
</div>
<p>Functions can be used in any expressions (eg. in the target”list or
qualifications):</p>
<div class="highlight-default"><div class="highlight"><pre><span class="gp">>>> </span><span class="nb">print</span><span class="p">(</span><span class="n">db</span><span class="o">.</span><span class="n">query</span><span class="p">(</span><span class="s">"SELECT one() AS answer"</span><span class="p">))</span>
<span class="go">answer</span>
<span class="go">------</span>
<span class="go"> 1</span>
<span class="go">(1 row)</span>
</pre></div>
</div>
<p>Here’s how you create a function that takes arguments. The following function
returns the sum of its two arguments:</p>
<div class="highlight-default"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">query</span><span class="p">(</span><span class="s">"""CREATE FUNCTION add_em(int4, int4) RETURNS int4</span>
<span class="gp">... </span><span class="s"> AS $$ SELECT $1 + $2 $$ LANGUAGE SQL"""</span><span class="p">)</span>
<span class="gp">>>> </span><span class="nb">print</span><span class="p">(</span><span class="n">query</span><span class="p">(</span><span class="s">"SELECT add_em(1, 2) AS answer"</span><span class="p">))</span>
<span class="go">answer</span>
<span class="go">------</span>
<span class="go"> 3</span>
<span class="go">(1 row)</span>
</pre></div>
</div>
</div>
<div class="section" id="creating-sql-functions-on-composite-types">
<h2>Creating SQL Functions on Composite Types<a class="headerlink" href="#creating-sql-functions-on-composite-types" title="Permalink to this headline">¶</a></h2>
<p>It is also possible to create functions that return values of composite types.</p>
<p>Before we create more sophisticated functions, let’s populate an EMP table:</p>
<div class="highlight-default"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">query</span><span class="p">(</span><span class="s">"""CREATE TABLE EMP (</span>
<span class="gp">... </span><span class="s"> name text,</span>
<span class="gp">... </span><span class="s"> salary int4,</span>
<span class="gp">... </span><span class="s"> age f int4,</span>
<span class="gp">... </span><span class="s"> dept varchar(16))"""</span><span class="p">)</span>
<span class="gp">>>> </span><span class="n">emps</span> <span class="o">=</span> <span class="p">[</span><span class="s">"'Sam', 1200, 16, 'toy'"</span><span class="p">,</span>
<span class="gp">... </span> <span class="s">"'Claire', 5000, 32, 'shoe'"</span><span class="p">,</span>
<span class="gp">... </span> <span class="s">"'Andy', -1000, 2, 'candy'"</span><span class="p">,</span>
<span class="gp">... </span> <span class="s">"'Bill', 4200, 36, 'shoe'"</span><span class="p">,</span>
<span class="gp">... </span> <span class="s">"'Ginger', 4800, 30, 'candy'"</span><span class="p">]</span>
<span class="gp">>>> </span><span class="k">for</span> <span class="n">emp</span> <span class="ow">in</span> <span class="n">emps</span><span class="p">:</span>
<span class="gp">... </span> <span class="n">query</span><span class="p">(</span><span class="s">"INSERT INTO EMP VALUES (%s)"</span> <span class="o">%</span> <span class="n">emp</span><span class="p">)</span>
</pre></div>
</div>
<p>Every INSERT statement will return a ‘1’ indicating that it has inserted
one row into the EMP table.</p>
<p>The argument of a function can also be a tuple. For instance, <em>double_salary</em>
takes a tuple of the EMP table:</p>
<div class="highlight-default"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">query</span><span class="p">(</span><span class="s">"""CREATE FUNCTION double_salary(EMP) RETURNS int4</span>
<span class="gp">... </span><span class="s"> AS $$ SELECT $1.salary * 2 AS salary $$ LANGUAGE SQL"""</span><span class="p">)</span>
<span class="gp">>>> </span><span class="nb">print</span><span class="p">(</span><span class="n">query</span><span class="p">(</span><span class="s">"""SELECT name, double_salary(EMP) AS dream</span>
<span class="gp">... </span><span class="s"> FROM EMP WHERE EMP.dept = 'toy'"""</span><span class="p">))</span>
<span class="go">name|dream</span>
<span class="go">----+-----</span>
<span class="go">Sam | 2400</span>
<span class="go">(1 row)</span>
</pre></div>
</div>
<p>The return value of a function can also be a tuple. However, make sure that the
expressions in the target list are in the same order as the columns of EMP:</p>
<div class="highlight-default"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">query</span><span class="p">(</span><span class="s">"""CREATE FUNCTION new_emp() RETURNS EMP AS $$</span>
<span class="gp">... </span><span class="s"> SELECT 'None'::text AS name,</span>
<span class="gp">... </span><span class="s"> 1000 AS salary,</span>
<span class="gp">... </span><span class="s"> 25 AS age,</span>
<span class="gp">... </span><span class="s"> 'None'::varchar(16) AS dept</span>
<span class="gp">... </span><span class="s"> $$ LANGUAGE SQL"""</span><span class="p">)</span>
</pre></div>
</div>
<p>You can then project a column out of resulting the tuple by using the
“function notation” for projection columns (i.e. <code class="docutils literal"><span class="pre">bar(foo)</span></code> is equivalent
to <code class="docutils literal"><span class="pre">foo.bar</span></code>). Note that <code class="docutils literal"><span class="pre">new_emp().name</span></code> isn’t supported:</p>
<div class="highlight-default"><div class="highlight"><pre><span class="gp">>>> </span><span class="nb">print</span><span class="p">(</span><span class="n">query</span><span class="p">(</span><span class="s">"SELECT name(new_emp()) AS nobody"</span><span class="p">))</span>
<span class="go">nobody</span>
<span class="go">------</span>
<span class="go">None</span>
<span class="go">(1 row)</span>
</pre></div>
</div>
<p>Let’s try one more function that returns tuples:</p>
<div class="highlight-default"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">query</span><span class="p">(</span><span class="s">"""CREATE FUNCTION high_pay() RETURNS setof EMP</span>
<span class="gp">... </span><span class="s"> AS 'SELECT * FROM EMP where salary > 1500'</span>
<span class="gp">... </span><span class="s"> LANGUAGE SQL"""</span><span class="p">)</span>
<span class="gp">>>> </span><span class="n">query</span><span class="p">(</span><span class="s">"SELECT name(high_pay()) AS overpaid"</span><span class="p">)</span>
<span class="go">overpaid</span>
<span class="go">--------</span>
<span class="go">Claire</span>
<span class="go">Bill</span>
<span class="go">Ginger</span>
<span class="go">(3 rows)</span>
</pre></div>
</div>
</div>
<div class="section" id="creating-sql-functions-with-multiple-sql-statements">
<h2>Creating SQL Functions with multiple SQL statements<a class="headerlink" href="#creating-sql-functions-with-multiple-sql-statements" title="Permalink to this headline">¶</a></h2>
<p>You can also create functions that do more than just a SELECT.</p>
<p>You may have noticed that Andy has a negative salary. We’ll create a function
that removes employees with negative salaries:</p>
<div class="highlight-default"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">query</span><span class="p">(</span><span class="s">"SELECT * FROM EMP"</span><span class="p">)</span>
<span class="go"> name |salary|age|dept</span>
<span class="go">------+------+---+-----</span>
<span class="go">Sam | 1200| 16|toy</span>
<span class="go">Claire| 5000| 32|shoe</span>
<span class="go">Andy | -1000| 2|candy</span>
<span class="go">Bill | 4200| 36|shoe</span>
<span class="go">Ginger| 4800| 30|candy</span>
<span class="go">(5 rows)</span>
<span class="gp">>>> </span><span class="n">query</span><span class="p">(</span><span class="s">"""CREATE FUNCTION clean_EMP () RETURNS int4 AS</span>
<span class="gp">... </span><span class="s"> 'DELETE FROM EMP WHERE EMP.salary <= 0;</span>
<span class="gp">... </span><span class="s"> SELECT 1 AS ignore_this'</span>
<span class="gp">... </span><span class="s"> LANGUAGE SQL"""</span><span class="p">)</span>
<span class="gp">>>> </span><span class="n">query</span><span class="p">(</span><span class="s">"SELECT clean_EMP()"</span><span class="p">)</span>
<span class="go">clean_emp</span>
<span class="go">---------</span>
<span class="go"> 1</span>
<span class="go">(1 row)</span>
<span class="gp">>>> </span><span class="n">query</span><span class="p">(</span><span class="s">"SELECT * FROM EMP"</span><span class="p">)</span>
<span class="go"> name |salary|age|dept</span>
<span class="go">------+------+---+-----</span>
<span class="go">Sam | 1200| 16|toy</span>
<span class="go">Claire| 5000| 32|shoe</span>
<span class="go">Bill | 4200| 36|shoe</span>
<span class="go">Ginger| 4800| 30|candy</span>
<span class="go">(4 rows)</span>
</pre></div>
</div>
</div>
<div class="section" id="remove-functions-that-were-created-in-this-example">
<h2>Remove functions that were created in this example<a class="headerlink" href="#remove-functions-that-were-created-in-this-example" title="Permalink to this headline">¶</a></h2>
<p>We can remove the functions that we have created in this example and the
table EMP, by using the DROP command:</p>
<div class="highlight-default"><div class="highlight"><pre><span class="n">query</span><span class="p">(</span><span class="s">"DROP FUNCTION clean_EMP()"</span><span class="p">)</span>
<span class="n">query</span><span class="p">(</span><span class="s">"DROP FUNCTION high_pay()"</span><span class="p">)</span>
<span class="n">query</span><span class="p">(</span><span class="s">"DROP FUNCTION new_emp()"</span><span class="p">)</span>
<span class="n">query</span><span class="p">(</span><span class="s">"DROP FUNCTION add_em(int4, int4)"</span><span class="p">)</span>
<span class="n">query</span><span class="p">(</span><span class="s">"DROP FUNCTION one()"</span><span class="p">)</span>
<span class="n">query</span><span class="p">(</span><span class="s">"DROP TABLE EMP CASCADE"</span><span class="p">)</span>
</pre></div>
</div>
</div>
</div>
</div>
</div>
</div>
<div class="sphinxsidebar" role="navigation" aria-label="main navigation">
<div class="sphinxsidebarwrapper">
<p class="logo"><a href="../index.html" title="contents/index">
<img class="logo" src="../../_static/pygresql.png" alt="Logo"/>
</a></p><div class="sphinxlocaltoc">
<h3><a href="../../index.html">Page contents</a></h3>
<ul>
<li><a class="reference internal" href="#">Examples for using SQL functions</a><ul>
<li><a class="reference internal" href="#creating-sql-functions-on-base-types">Creating SQL Functions on Base Types</a></li>
<li><a class="reference internal" href="#creating-sql-functions-on-composite-types">Creating SQL Functions on Composite Types</a></li>
<li><a class="reference internal" href="#creating-sql-functions-with-multiple-sql-statements">Creating SQL Functions with multiple SQL statements</a></li>
<li><a class="reference internal" href="#remove-functions-that-were-created-in-this-example">Remove functions that were created in this example</a></li>
</ul>
</li>
</ul>
</div>
<div class="sphinxprev">
<h4>Previous page</h4>
<p class="topless"><a href="advanced.html"
title="Previous page">← Examples for advanced features</a></p>
</div>
<div class="sphinxnext">
<h4>Next page</h4>
<p class="topless"><a href="syscat.html"
title="Next page">→ Examples for using the system catalogs</a></p>
</div>
<div role="note" aria-label="source link">
<h3>This Page</h3>
<ul class="this-page-menu">
<li><a href="../../_sources/contents/postgres/func.txt"
rel="nofollow">Show Source</a></li>
</ul>
</div>
<div id="searchbox" style="display: none" role="search">
<h3>Quick search</h3>
<form class="search" action="../../search.html" method="get">
<input type="text" name="q" />
<input type="submit" value="Go" />
<input type="hidden" name="check_keywords" value="yes" />
<input type="hidden" name="area" value="default" />
</form>
</div>
<script type="text/javascript">$('#searchbox').show(0);</script>
</div>
</div>
<div class="clearer"></div>
</div>
<div class="relbar-bottom">
<div class="related" role="navigation" aria-label="related navigation">
<h3>Navigation</h3>
<ul>
<li class="right" style="margin-right: 10px">
<a href="../../genindex.html" title="General Index"
>index</a></li>
<li class="right" >
<a href="../../py-modindex.html" title="Python Module Index"
>modules</a> </li>
<li class="right" >
<a href="syscat.html" title="Examples for using the system catalogs"
>next</a> </li>
<li class="right" >
<a href="advanced.html" title="Examples for advanced features"
>previous</a> </li>
<li><a href="../index.html">PyGreSQL 5.0 documentation</a> »</li>
<li class="nav-item nav-item-1"><a href="index.html" >A PostgreSQL Primer</a> »</li>
</ul>
</div>
</div>
<div class="footer" role="contentinfo">
© <a href="../../copyright.html">Copyright</a> 2016, The PyGreSQL team.
Created using <a href="http://sphinx-doc.org/">Sphinx</a> 1.4.1.
</div>
<!-- cloud_sptheme 1.4 -->
</body>
</html>
|