mirror of
https://github.com/mariadb-corporation/mariadb-connector-python.git
synced 2025-08-02 13:56:54 +00:00

Insted of parsing a short int (16 bits, "h" option in PyArg_ParseTuple) we need to parse 32bit option "i"
303 lines
22 KiB
HTML
303 lines
22 KiB
HTML
|
||
<!DOCTYPE html>
|
||
|
||
<html>
|
||
<head>
|
||
<meta charset="utf-8" />
|
||
<meta name="viewport" content="width=device-width, initial-scale=1.0" />
|
||
<title>Basic usage — MariaDB Connector/Python 1.1.1-alpha documentation</title>
|
||
<link rel="stylesheet" type="text/css" href="_static/pygments.css" />
|
||
<link rel="stylesheet" type="text/css" href="_static/classic.css" />
|
||
|
||
<script data-url_root="./" id="documentation_options" src="_static/documentation_options.js"></script>
|
||
<script src="_static/jquery.js"></script>
|
||
<script src="_static/underscore.js"></script>
|
||
<script src="_static/doctools.js"></script>
|
||
|
||
<link rel="index" title="Index" href="genindex.html" />
|
||
<link rel="search" title="Search" href="search.html" />
|
||
<link rel="next" title="The mariadb module" href="module.html" />
|
||
<link rel="prev" title="Installation" href="install.html" />
|
||
</head><body>
|
||
<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="module.html" title="The mariadb module"
|
||
accesskey="N">next</a> |</li>
|
||
<li class="right" >
|
||
<a href="install.html" title="Installation"
|
||
accesskey="P">previous</a> |</li>
|
||
<li class="nav-item nav-item-0"><a href="index.html">MariaDB Connector/Python 1.1.1-alpha documentation</a> »</li>
|
||
<li class="nav-item nav-item-this"><a href="">Basic usage</a></li>
|
||
</ul>
|
||
</div>
|
||
|
||
<div class="document">
|
||
<div class="documentwrapper">
|
||
<div class="bodywrapper">
|
||
<div class="body" role="main">
|
||
|
||
<div class="section" id="basic-usage">
|
||
<h1>Basic usage<a class="headerlink" href="#basic-usage" title="Permalink to this headline">¶</a></h1>
|
||
<div class="section" id="connecting">
|
||
<h2>Connecting<a class="headerlink" href="#connecting" title="Permalink to this headline">¶</a></h2>
|
||
<p>The basic usage of MariaDB Connector/Python is similar to other database drivers which
|
||
implement DB API 2.0 (PEP-249).</p>
|
||
<p>Below is a simple example of a typical use of MariaDB Connector/Python</p>
|
||
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="linenos"> 1</span><span class="c1"># Import MariaDB Connector/Python module</span>
|
||
<span class="linenos"> 2</span><span class="kn">import</span> <span class="nn">mariadb</span>
|
||
<span class="linenos"> 3</span>
|
||
<span class="linenos"> 4</span><span class="c1"># Establish a connection</span>
|
||
<span class="linenos"> 5</span><span class="n">connection</span><span class="o">=</span> <span class="n">mariadb</span><span class="o">.</span><span class="n">connect</span><span class="p">(</span><span class="n">user</span><span class="o">=</span><span class="s2">"myuser"</span><span class="p">,</span> <span class="n">database</span><span class="o">=</span><span class="s2">"test"</span><span class="p">,</span> <span class="n">host</span><span class="o">=</span><span class="s2">"localhost"</span><span class="p">)</span>
|
||
<span class="linenos"> 6</span>
|
||
<span class="linenos"> 7</span><span class="n">cursor</span><span class="o">=</span> <span class="n">connection</span><span class="o">.</span><span class="n">cursor</span><span class="p">()</span>
|
||
<span class="linenos"> 8</span>
|
||
<span class="linenos"> 9</span><span class="c1"># Create a database table</span>
|
||
<span class="linenos">10</span><span class="n">cursor</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"DROP TABLE IF EXISTS mytest"</span><span class="p">)</span>
|
||
<span class="linenos">11</span><span class="n">cursor</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"CREATE TABLE mytest(id INT UNSIGNED AUTO_INCREMENT PRIMARY KEY,"</span>
|
||
<span class="linenos">12</span> <span class="s2">"first_name VARCHAR(100), last_name VARCHAR(100))"</span><span class="p">)</span>
|
||
<span class="linenos">13</span>
|
||
<span class="linenos">14</span>
|
||
<span class="linenos">15</span><span class="c1"># Populate table with some data</span>
|
||
<span class="linenos">16</span><span class="n">cursor</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"INSERT INTO mytest(first_name, last_name) VALUES (?,?)"</span><span class="p">,</span>
|
||
<span class="linenos">17</span> <span class="p">(</span><span class="s2">"Robert"</span><span class="p">,</span> <span class="s2">"Redford"</span><span class="p">))</span>
|
||
<span class="linenos">18</span>
|
||
<span class="linenos">19</span><span class="c1"># retrieve data</span>
|
||
<span class="linenos">20</span><span class="n">cursor</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"SELECT id, first_name, last_name FROM mytest"</span><span class="p">)</span>
|
||
<span class="linenos">21</span>
|
||
<span class="linenos">22</span><span class="c1"># print content</span>
|
||
<span class="linenos">23</span><span class="n">row</span><span class="o">=</span> <span class="n">cursor</span><span class="o">.</span><span class="n">fetchone</span><span class="p">()</span>
|
||
<span class="linenos">24</span><span class="nb">print</span><span class="p">(</span><span class="o">*</span><span class="n">row</span><span class="p">,</span> <span class="n">sep</span><span class="o">=</span><span class="s1">'</span><span class="se">\t</span><span class="s1">'</span><span class="p">)</span>
|
||
<span class="linenos">25</span>
|
||
<span class="linenos">26</span><span class="c1"># free resources</span>
|
||
<span class="linenos">27</span><span class="n">cursor</span><span class="o">.</span><span class="n">close</span><span class="p">()</span>
|
||
<span class="linenos">28</span><span class="n">connection</span><span class="o">.</span><span class="n">close</span><span class="p">()</span>
|
||
</pre></div>
|
||
</div>
|
||
<p>Before MariaDB Connector/Python can be used, the MariaDB Connector/Python module must be
|
||
imported (line #2)
|
||
Once the mariadb module is loaded, a connection to a database server will be established
|
||
using the method <a class="reference internal" href="module.html#mariadb.connect" title="mariadb.connect"><code class="xref py py-func docutils literal notranslate"><span class="pre">connect()</span></code></a> (line #5).</p>
|
||
<p>In order to be able to communicate with the database server in the form of SQL statements,
|
||
a cursor object must be created first (line #7).</p>
|
||
<p>The method name cursor may be a little misleading: unlike a cursor in MariaDB that can only
|
||
read and return data, a cursor in Python can be used for all types of SQL statements.</p>
|
||
<p>After creating the table mytest, everything is ready to insert some data (line #16): Column values
|
||
that are to be inserted in the database are identified by place holders, the data is then passed in
|
||
the form of a tuple as a second parameter (line #16).</p>
|
||
<p>After creating and populating the table mytest the cursor will be used to retrieve the data (line #20 - line#23).</p>
|
||
</div>
|
||
<div class="section" id="passing-parameters-to-sql-statements">
|
||
<h2>Passing parameters to SQL statements<a class="headerlink" href="#passing-parameters-to-sql-statements" title="Permalink to this headline">¶</a></h2>
|
||
<p>As shown in previous example, passing parameters to SQL statements happens by using placeholders in the statement. By default
|
||
MariaDB Connector/Python uses a question mark as a placeholder, for compatibility reason also %s placeholders are supported. Passing
|
||
parameters is supported in methods <code class="xref py py-func docutils literal notranslate"><span class="pre">execute()</span></code> and <code class="xref py py-func docutils literal notranslate"><span class="pre">executemany()</span></code> of the cursor class.</p>
|
||
<p>Since MariaDB Connector/Python uses binary protocol, escaping strings or binary data like in other database drivers is not required.</p>
|
||
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="linenos"> 1</span><span class="c1"># update</span>
|
||
<span class="linenos"> 2</span><span class="n">sql</span><span class="o">=</span> <span class="s2">"UPDATE books SET price=? WHERE book_name=?"</span>
|
||
<span class="linenos"> 3</span><span class="n">data</span><span class="o">=</span> <span class="p">(</span><span class="mf">14.90</span><span class="p">,</span> <span class="s2">"Dream of the Red Chamber"</span><span class="p">)</span>
|
||
<span class="linenos"> 4</span><span class="n">cursor</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="n">sql</span><span class="p">,</span> <span class="n">data</span><span class="p">)</span>
|
||
<span class="linenos"> 5</span>
|
||
<span class="linenos"> 6</span><span class="c1"># delete</span>
|
||
<span class="linenos"> 7</span><span class="n">sql</span><span class="o">=</span> <span class="s2">"DELETE FROM books WHERE id=?"</span>
|
||
<span class="linenos"> 8</span><span class="n">data</span><span class="o">=</span> <span class="p">(</span><span class="mi">4034</span><span class="p">,)</span> <span class="c1"># Don't forget a comma at the end!</span>
|
||
<span class="linenos"> 9</span><span class="n">cursor</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="n">sql</span><span class="p">,</span> <span class="n">data</span><span class="p">)</span>
|
||
<span class="linenos">10</span>
|
||
<span class="linenos">11</span>
|
||
<span class="linenos">12</span><span class="c1"># insert</span>
|
||
<span class="linenos">13</span><span class="n">sql</span><span class="o">=</span> <span class="s2">"INSERT INTO books (book_name, author_name, price) VALUES (?, ?, ?)"</span>
|
||
<span class="linenos">14</span><span class="n">data</span><span class="o">=</span> <span class="p">(</span><span class="s2">"The Lord of the Rings"</span><span class="p">,</span> <span class="s2">"J.R.R. Tolkien"</span><span class="p">,</span> <span class="mf">18.99</span><span class="p">)</span>
|
||
</pre></div>
|
||
</div>
|
||
<p>Often there is a requirement to update, delete or insert multiple records. This could be done be using <code class="xref py py-func docutils literal notranslate"><span class="pre">execute()</span></code> in
|
||
a loop, but much more effective is using the <code class="xref py py-func docutils literal notranslate"><span class="pre">executemany()</span></code> method, especially when using a MariaDB database server 10.2 and above, which supports a special “bulk” protocol. The executemany() works similar to execute(), but accepts data as a list of tuples:</p>
|
||
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="linenos"> 1</span><span class="c1"># update</span>
|
||
<span class="linenos"> 2</span><span class="n">sql</span><span class="o">=</span> <span class="s2">"UPDATE books SET price=? WHERE book_name=?"</span>
|
||
<span class="linenos"> 3</span><span class="n">data</span><span class="o">=</span> <span class="p">[(</span><span class="mf">14.90</span><span class="p">,</span> <span class="s2">"Dream of the Red Chamber"</span><span class="p">),</span>
|
||
<span class="linenos"> 4</span> <span class="p">(</span><span class="mf">22.30</span><span class="p">,</span> <span class="s2">"The Master and Margarita"</span><span class="p">),</span>
|
||
<span class="linenos"> 5</span> <span class="p">(</span><span class="mf">17.10</span><span class="p">,</span> <span class="s2">"And Then There Were None"</span><span class="p">)]</span>
|
||
<span class="linenos"> 6</span><span class="n">cursor</span><span class="o">.</span><span class="n">executemany</span><span class="p">(</span><span class="n">sql</span><span class="p">,</span> <span class="n">data</span><span class="p">)</span>
|
||
<span class="linenos"> 7</span>
|
||
<span class="linenos"> 8</span><span class="c1"># delete</span>
|
||
<span class="linenos"> 9</span><span class="n">sql</span><span class="o">=</span> <span class="s2">"DELETE FROM books WHERE id=?"</span>
|
||
<span class="linenos">10</span><span class="n">data</span><span class="o">=</span> <span class="p">[(</span><span class="mi">4034</span><span class="p">,),(</span><span class="mi">12001</span><span class="p">,),(</span><span class="mi">230</span><span class="p">,)]</span>
|
||
<span class="linenos">11</span><span class="n">cursor</span><span class="o">.</span><span class="n">executemany</span><span class="p">(</span><span class="n">sql</span><span class="p">,</span> <span class="n">data</span><span class="p">)</span>
|
||
<span class="linenos">12</span>
|
||
<span class="linenos">13</span><span class="c1">#insert</span>
|
||
<span class="linenos">14</span><span class="n">sql</span><span class="o">=</span> <span class="s2">"INSERT INTO books (book_name, author_name, price) VALUES (?, ?, ?)"</span>
|
||
<span class="linenos">15</span><span class="n">data</span><span class="o">=</span> <span class="p">[(</span><span class="s2">"The Lord of the Rings"</span><span class="p">,</span> <span class="s2">"J.R.R. Tolkien"</span><span class="p">,</span> <span class="mf">18.99</span><span class="p">),</span>
|
||
<span class="linenos">16</span> <span class="p">(</span><span class="s2">"Le Petit Prince"</span><span class="p">,</span> <span class="s2">"Antoine de Saint-Exupéry"</span><span class="p">,</span> <span class="mf">22.40</span><span class="p">),</span>
|
||
<span class="linenos">17</span> <span class="p">(</span><span class="s2">"Dream of the Red Chamber"</span><span class="p">,</span> <span class="s2">"Cao Xueqin"</span><span class="p">,</span> <span class="mf">16.90</span><span class="p">),</span>
|
||
<span class="linenos">18</span> <span class="p">(</span><span class="s2">"The Adventures of Pinocchio"</span><span class="p">,</span> <span class="s2">"Carlo Collodi"</span><span class="p">,</span> <span class="mf">17.10</span><span class="p">)]</span>
|
||
<span class="linenos">19</span><span class="n">cursor</span><span class="o">.</span><span class="n">executemany</span><span class="p">(</span><span class="n">sql</span><span class="p">,</span> <span class="n">data</span><span class="p">)</span>
|
||
</pre></div>
|
||
</div>
|
||
<p>When using executemany(), there are a few restrictions:
|
||
- All tuples must have the same types as in first tuple. E.g. the parameter [(1),(1.0)] or [(1),(None)] are invalid.
|
||
- Special values like None or column default value needs to be indicated by an indicator.</p>
|
||
<div class="section" id="using-indicators">
|
||
<h3>Using indicators<a class="headerlink" href="#using-indicators" title="Permalink to this headline">¶</a></h3>
|
||
<p>In certain situations, for example when inserting default values or NULL, special indicators must be used.</p>
|
||
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="linenos">1</span><span class="kn">from</span> <span class="nn">mariadb.constants</span> <span class="kn">import</span> <span class="o">*</span>
|
||
<span class="linenos">2</span>
|
||
<span class="linenos">3</span><span class="n">cursor</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"CREATE TABLE cakes(id int, cake varchar(100), price decimal(10,2) default 1.99)"</span><span class="p">)</span>
|
||
<span class="linenos">4</span>
|
||
<span class="linenos">5</span><span class="n">sql</span><span class="o">=</span> <span class="s2">"INSERT INTO cakes (id, cake, price) VALUES (?,?)"</span>
|
||
<span class="linenos">6</span><span class="n">data</span><span class="o">=</span> <span class="p">[(</span><span class="mi">1</span><span class="p">,</span> <span class="s2">"Cherry Cake"</span><span class="p">,</span> <span class="mf">2.10</span><span class="p">),</span> <span class="p">(</span><span class="mi">2</span><span class="p">,</span> <span class="s2">"Apple Cake"</span><span class="p">,</span> <span class="n">INDICATOR</span><span class="o">.</span><span class="n">default</span><span class="p">)]</span>
|
||
<span class="linenos">7</span><span class="n">cursor</span><span class="o">.</span><span class="n">executemany</span><span class="p">(</span><span class="n">sql</span><span class="p">,</span> <span class="n">data</span><span class="p">)</span>
|
||
</pre></div>
|
||
</div>
|
||
<dl class="simple">
|
||
<dt>Beside the default indicator which inserts the default value of 1.99, the following indicators are supported:</dt><dd><ul class="simple">
|
||
<li><p>INDICATOR.IGNORE: Ignores the value (only update commands)</p></li>
|
||
<li><p>INDICATOR.NULL: Value is NULL</p></li>
|
||
<li><p>INDICATOR.IGNORE_ROW: Don’t update or insert row</p></li>
|
||
</ul>
|
||
</dd>
|
||
</dl>
|
||
<div class="admonition note">
|
||
<p class="admonition-title">Note</p>
|
||
<ul class="simple">
|
||
<li><p>Mixing different parameter styles is not supported and will raise an exception</p></li>
|
||
<li><p>The Python string operator % must not be used. The <code class="xref py py-func docutils literal notranslate"><span class="pre">execute()</span></code> method accepts a tuple or list as second parameter.</p></li>
|
||
<li><p>Placeholders between quotation marks are interpreted as a string.</p></li>
|
||
<li><p>Parameters for <code class="xref py py-func docutils literal notranslate"><span class="pre">execute()</span></code> needs to be passed as a tuple. If only one parameter will be passed, tuple needs to contain a comma at the end.</p></li>
|
||
<li><p>Parameters for <code class="xref py py-func docutils literal notranslate"><span class="pre">executemany()</span></code> need to be passed as a list of tuples.</p></li>
|
||
</ul>
|
||
</div>
|
||
<div class="section" id="supported-data-types">
|
||
<h4>Supported Data types<a class="headerlink" href="#supported-data-types" title="Permalink to this headline">¶</a></h4>
|
||
<p>Several standard python types are converted into SQL types and returned as Python objects when a statement is executed.</p>
|
||
<table class="docutils align-left" id="id1">
|
||
<caption><span class="caption-text">Supported Data Types</span><a class="headerlink" href="#id1" title="Permalink to this table">¶</a></caption>
|
||
<colgroup>
|
||
<col style="width: 50%" />
|
||
<col style="width: 50%" />
|
||
</colgroup>
|
||
<thead>
|
||
<tr class="row-odd"><th class="head"><p>Python type</p></th>
|
||
<th class="head"><p>SQL type</p></th>
|
||
</tr>
|
||
</thead>
|
||
<tbody>
|
||
<tr class="row-even"><td><p>None</p></td>
|
||
<td><p>NULL</p></td>
|
||
</tr>
|
||
<tr class="row-odd"><td><p>Bool</p></td>
|
||
<td><p>TINYINT</p></td>
|
||
</tr>
|
||
<tr class="row-even"><td><p>Float, Double</p></td>
|
||
<td><p>DOUBLE</p></td>
|
||
</tr>
|
||
<tr class="row-odd"><td><p>Decimal</p></td>
|
||
<td><p>DECIMAL</p></td>
|
||
</tr>
|
||
<tr class="row-even"><td><p>Long</p></td>
|
||
<td><p>TINYINT, SMALLINT, INT, BIGINT</p></td>
|
||
</tr>
|
||
<tr class="row-odd"><td><p>String</p></td>
|
||
<td><p>VARCHAR, VARSTRING, TEXT</p></td>
|
||
</tr>
|
||
<tr class="row-even"><td><p>ByteArray, Bytes</p></td>
|
||
<td><p>TINYBLOB, MEDIUMBLOB, BLOB, LONGBLOB</p></td>
|
||
</tr>
|
||
<tr class="row-odd"><td><p>DateTime</p></td>
|
||
<td><p>DATETIME</p></td>
|
||
</tr>
|
||
<tr class="row-even"><td><p>Date</p></td>
|
||
<td><p>DATE</p></td>
|
||
</tr>
|
||
<tr class="row-odd"><td><p>Time</p></td>
|
||
<td><p>TIME</p></td>
|
||
</tr>
|
||
<tr class="row-even"><td><p>Timestamp</p></td>
|
||
<td><p>TIMESTAMP</p></td>
|
||
</tr>
|
||
</tbody>
|
||
</table>
|
||
</div>
|
||
</div>
|
||
</div>
|
||
</div>
|
||
|
||
|
||
<div class="clearer"></div>
|
||
</div>
|
||
</div>
|
||
</div>
|
||
<div class="sphinxsidebar" role="navigation" aria-label="main navigation">
|
||
<div class="sphinxsidebarwrapper">
|
||
<h3><a href="index.html">Table of Contents</a></h3>
|
||
<ul>
|
||
<li><a class="reference internal" href="#">Basic usage</a><ul>
|
||
<li><a class="reference internal" href="#connecting">Connecting</a></li>
|
||
<li><a class="reference internal" href="#passing-parameters-to-sql-statements">Passing parameters to SQL statements</a><ul>
|
||
<li><a class="reference internal" href="#using-indicators">Using indicators</a><ul>
|
||
<li><a class="reference internal" href="#supported-data-types">Supported Data types</a></li>
|
||
</ul>
|
||
</li>
|
||
</ul>
|
||
</li>
|
||
</ul>
|
||
</li>
|
||
</ul>
|
||
|
||
<h4>Previous topic</h4>
|
||
<p class="topless"><a href="install.html"
|
||
title="previous chapter">Installation</a></p>
|
||
<h4>Next topic</h4>
|
||
<p class="topless"><a href="module.html"
|
||
title="next chapter">The mariadb module</a></p>
|
||
<div role="note" aria-label="source link">
|
||
<h3>This Page</h3>
|
||
<ul class="this-page-menu">
|
||
<li><a href="_sources/usage.rst.txt"
|
||
rel="nofollow">Show Source</a></li>
|
||
</ul>
|
||
</div>
|
||
<div id="searchbox" style="display: none" role="search">
|
||
<h3 id="searchlabel">Quick search</h3>
|
||
<div class="searchformwrapper">
|
||
<form class="search" action="search.html" method="get">
|
||
<input type="text" name="q" aria-labelledby="searchlabel" autocomplete="off" autocorrect="off" autocapitalize="off" spellcheck="false"/>
|
||
<input type="submit" value="Go" />
|
||
</form>
|
||
</div>
|
||
</div>
|
||
<script>$('#searchbox').show(0);</script>
|
||
</div>
|
||
</div>
|
||
<div class="clearer"></div>
|
||
</div>
|
||
<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="module.html" title="The mariadb module"
|
||
>next</a> |</li>
|
||
<li class="right" >
|
||
<a href="install.html" title="Installation"
|
||
>previous</a> |</li>
|
||
<li class="nav-item nav-item-0"><a href="index.html">MariaDB Connector/Python 1.1.1-alpha documentation</a> »</li>
|
||
<li class="nav-item nav-item-this"><a href="">Basic usage</a></li>
|
||
</ul>
|
||
</div>
|
||
<div class="footer" role="contentinfo">
|
||
© Copyright 2019-2021 MariaDB Corporation and Georg Richter.
|
||
Created using <a href="https://www.sphinx-doc.org/">Sphinx</a> 4.1.2.
|
||
</div>
|
||
</body>
|
||
</html> |