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 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782 783 784 785 786 787 788 789 790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855 856 857 858 859 860 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877 878 879 880 881 882 883 884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 902 903 904 905 906 907 908 909 910 911 912 913 914 915 916 917 918 919 920 921 922 923 924 925 926 927 928 929 930 931 932 933 934 935 936 937 938 939 940 941 942 943 944 945 946 947 948 949 950 951 952 953 954 955 956 957 958 959 960 961 962 963 964 965 966 967 968 969 970 971 972 973 974 975 976 977 978 979 980 981 982 983 984 985 986 987 988 989 990 991 992 993 994 995 996 997 998 999 1000 1001 1002 1003 1004 1005 1006 1007 1008 1009 1010 1011 1012 1013 1014 1015 1016 1017 1018 1019 1020 1021 1022 1023 1024 1025 1026 1027 1028 1029 1030 1031 1032 1033 1034 1035 1036 1037 1038 1039 1040 1041 1042 1043 1044 1045 1046 1047 1048 1049 1050 1051 1052 1053 1054 1055 1056 1057 1058 1059 1060 1061 1062 1063 1064 1065 1066 1067 1068 1069 1070 1071 1072 1073 1074 1075 1076 1077 1078 1079 1080 1081 1082 1083 1084 1085 1086 1087 1088 1089 1090 1091 1092 1093 1094 1095 1096 1097 1098 1099 1100 1101 1102 1103 1104 1105 1106 1107 1108 1109 1110 1111 1112 1113 1114 1115 1116 1117 1118 1119 1120 1121 1122 1123 1124 1125 1126 1127 1128 1129 1130 1131 1132 1133 1134 1135 1136 1137 1138 1139 1140 1141 1142 1143 1144 1145 1146 1147 1148 1149 1150 1151 1152 1153 1154 1155 1156 1157 1158 1159 1160 1161 1162 1163 1164 1165 1166 1167 1168 1169 1170 1171 1172 1173 1174 1175 1176 1177 1178 1179 1180 1181 1182 1183 1184 1185 1186 1187 1188 1189 1190 1191 1192 1193 1194 1195 1196 1197 1198 1199 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209 1210 1211 1212 1213 1214 1215 1216 1217 1218 1219 1220 1221 1222 1223 1224 1225 1226 1227 1228 1229 1230 1231 1232 1233 1234 1235 1236 1237 1238 1239 1240 1241 1242 1243 1244 1245 1246 1247 1248 1249 1250 1251 1252 1253 1254 1255 1256 1257 1258 1259 1260 1261 1262 1263 1264 1265 1266 1267 1268 1269 1270 1271 1272 1273 1274 1275 1276 1277 1278 1279 1280 1281 1282 1283 1284 1285 1286 1287 1288 1289 1290 1291 1292 1293 1294 1295 1296 1297 1298 1299 1300 1301 1302 1303 1304 1305 1306 1307 1308 1309 1310 1311 1312 1313 1314 1315 1316 1317 1318 1319 1320 1321 1322 1323 1324 1325 1326 1327 1328 1329 1330 1331 1332 1333 1334 1335 1336 1337 1338 1339 1340 1341 1342 1343 1344 1345 1346 1347 1348 1349 1350 1351 1352 1353 1354 1355 1356 1357 1358 1359 1360 1361 1362 1363 1364 1365 1366 1367 1368 1369 1370 1371 1372 1373 1374 1375 1376 1377 1378 1379 1380 1381 1382 1383 1384 1385 1386 1387 1388 1389 1390 1391 1392 1393 1394 1395 1396 1397 1398 1399 1400 1401 1402 1403 1404 1405 1406 1407 1408 1409 1410 1411 1412 1413 1414 1415 1416 1417 1418 1419 1420 1421 1422 1423 1424 1425 1426 1427 1428 1429 1430 1431 1432 1433 1434 1435 1436 1437 1438 1439 1440 1441 1442 1443 1444 1445 1446 1447 1448 1449 1450 1451 1452 1453 1454 1455 1456 1457 1458 1459 1460 1461 1462 1463 1464 1465 1466 1467 1468 1469 1470 1471 1472 1473 1474 1475 1476 1477 1478 1479 1480 1481 1482 1483 1484 1485 1486 1487 1488 1489 1490 1491 1492 1493 1494 1495 1496 1497 1498 1499 1500 1501 1502 1503 1504 1505 1506 1507 1508 1509 1510 1511 1512 1513 1514 1515 1516 1517 1518 1519 1520 1521 1522 1523 1524 1525 1526 1527 1528 1529 1530 1531 1532 1533 1534 1535 1536 1537 1538 1539 1540 1541 1542 1543 1544 1545 1546 1547 1548 1549 1550 1551 1552 1553 1554 1555 1556 1557 1558 1559 1560 1561 1562 1563 1564 1565 1566 1567 1568 1569 1570 1571 1572 1573 1574 1575 1576 1577 1578 1579 1580 1581 1582 1583 1584 1585 1586 1587 1588 1589 1590 1591 1592 1593 1594 1595 1596 1597 1598 1599 1600 1601 1602 1603 1604 1605 1606 1607 1608 1609 1610 1611 1612 1613 1614 1615 1616 1617 1618 1619 1620 1621 1622 1623 1624 1625 1626 1627 1628 1629 1630 1631 1632 1633 1634 1635 1636 1637 1638 1639 1640 1641 1642 1643 1644 1645 1646 1647 1648 1649 1650 1651 1652 1653 1654 1655 1656 1657 1658 1659 1660 1661 1662 1663 1664 1665 1666 1667 1668 1669 1670 1671 1672 1673 1674 1675 1676 1677 1678 1679 1680 1681 1682 1683 1684 1685 1686 1687 1688 1689 1690 1691 1692 1693 1694 1695 1696 1697 1698 1699 1700 1701 1702 1703 1704 1705 1706 1707 1708 1709 1710 1711 1712 1713 1714 1715 1716 1717 1718 1719 1720 1721 1722 1723 1724 1725 1726 1727 1728 1729 1730 1731 1732 1733 1734 1735 1736 1737 1738 1739 1740 1741 1742 1743 1744 1745 1746 1747 1748 1749 1750 1751 1752 1753 1754 1755 1756 1757 1758 1759 1760 1761 1762 1763 1764 1765 1766 1767 1768 1769 1770 1771 1772 1773 1774 1775 1776 1777 1778 1779 1780 1781 1782 1783 1784 1785 1786 1787 1788 1789 1790 1791 1792 1793 1794 1795 1796 1797 1798 1799 1800 1801 1802 1803 1804 1805 1806 1807 1808 1809 1810 1811 1812 1813 1814 1815 1816 1817 1818 1819 1820 1821 1822 1823 1824 1825 1826 1827 1828 1829 1830 1831 1832 1833 1834 1835 1836 1837 1838 1839 1840 1841 1842 1843 1844 1845 1846 1847 1848 1849 1850 1851 1852 1853 1854 1855 1856 1857 1858 1859 1860 1861 1862 1863 1864 1865 1866 1867 1868 1869 1870 1871 1872 1873 1874 1875 1876 1877 1878 1879 1880 1881 1882 1883 1884 1885 1886 1887 1888 1889 1890 1891 1892 1893 1894 1895 1896 1897 1898 1899 1900 1901 1902 1903 1904 1905 1906 1907 1908 1909 1910 1911 1912 1913 1914 1915 1916 1917 1918 1919 1920 1921 1922 1923 1924 1925 1926 1927 1928 1929 1930 1931 1932 1933 1934 1935 1936 1937 1938 1939 1940 1941 1942 1943 1944 1945 1946 1947 1948 1949 1950 1951 1952 1953 1954 1955 1956 1957 1958 1959 1960 1961 1962 1963 1964 1965 1966 1967
|
<!DOCTYPE html>
<html class="writer-html5" lang="en" data-content_root="./">
<head>
<meta charset="utf-8" /><meta name="viewport" content="width=device-width, initial-scale=1" />
<meta name="viewport" content="width=device-width, initial-scale=1.0" />
<title>Example/Tour — APSW 3.46.0.1 documentation</title>
<link rel="stylesheet" type="text/css" href="_static/pygments.css?v=72bcf2f2" />
<link rel="stylesheet" type="text/css" href="_static/css/theme.css?v=19f00094" />
<link rel="stylesheet" type="text/css" href="_static/apsw.css?v=3c7e2631" />
<link rel="shortcut icon" href="_static/favicon.ico"/>
<!--[if lt IE 9]>
<script src="_static/js/html5shiv.min.js"></script>
<![endif]-->
<script src="_static/jquery.js?v=5d32c60e"></script>
<script src="_static/_sphinx_javascript_frameworks_compat.js?v=2cd50e6c"></script>
<script src="_static/documentation_options.js?v=d98f5d2b"></script>
<script src="_static/doctools.js?v=9a2dae69"></script>
<script src="_static/sphinx_highlight.js?v=dc90522c"></script>
<script src="_static/js/theme.js"></script>
<link rel="author" title="About these documents" href="about.html" />
<link rel="index" title="Index" href="genindex.html" />
<link rel="search" title="Search" href="search.html" />
<link rel="copyright" title="Copyright" href="copyright.html" />
<link rel="next" title="Installation and customization" href="install.html" />
<link rel="prev" title="Tips" href="tips.html" />
</head>
<body class="wy-body-for-nav">
<div class="wy-grid-for-nav">
<nav data-toggle="wy-nav-shift" class="wy-nav-side">
<div class="wy-side-scroll">
<div class="wy-side-nav-search" >
<a href="index.html" class="icon icon-home">
APSW
<img src="_static/apswlogo.png" class="logo" alt="Logo"/>
</a>
<div class="version">
3.46.0.1
</div>
<div role="search">
<form id="rtd-search-form" class="wy-form" action="search.html" method="get">
<input type="text" name="q" placeholder="Search docs" aria-label="Search docs" />
<input type="hidden" name="check_keywords" value="yes" />
<input type="hidden" name="area" value="default" />
</form>
</div>
</div><div class="wy-menu wy-menu-vertical" data-spy="affix" role="navigation" aria-label="Navigation menu">
<ul class="current">
<li class="toctree-l1"><a class="reference internal" href="about.html">About</a></li>
<li class="toctree-l1"><a class="reference internal" href="tips.html">Tips</a></li>
<li class="toctree-l1 current"><a class="current reference internal" href="#">Example/Tour</a><ul>
<li class="toctree-l2"><a class="reference internal" href="#checking-apsw-and-sqlite-versions">Checking APSW and SQLite versions</a></li>
<li class="toctree-l2"><a class="reference internal" href="#best-practice">Best Practice</a></li>
<li class="toctree-l2"><a class="reference internal" href="#logging">Logging</a></li>
<li class="toctree-l2"><a class="reference internal" href="#opening-the-database">Opening the database</a></li>
<li class="toctree-l2"><a class="reference internal" href="#executing-sql">Executing SQL</a></li>
<li class="toctree-l2"><a class="reference internal" href="#why-you-use-bindings-to-provide-values">Why you use bindings to provide values</a></li>
<li class="toctree-l2"><a class="reference internal" href="#bindings-sequence">Bindings (sequence)</a></li>
<li class="toctree-l2"><a class="reference internal" href="#bindings-dict">Bindings (dict)</a></li>
<li class="toctree-l2"><a class="reference internal" href="#transactions">Transactions</a></li>
<li class="toctree-l2"><a class="reference internal" href="#executemany">executemany</a></li>
<li class="toctree-l2"><a class="reference internal" href="#pragmas">Pragmas</a></li>
<li class="toctree-l2"><a class="reference internal" href="#tracing-execution">Tracing execution</a></li>
<li class="toctree-l2"><a class="reference internal" href="#tracing-returned-rows">Tracing returned rows</a></li>
<li class="toctree-l2"><a class="reference internal" href="#defining-scalar-functions">Defining scalar functions</a></li>
<li class="toctree-l2"><a class="reference internal" href="#defining-aggregate-functions">Defining aggregate functions</a></li>
<li class="toctree-l2"><a class="reference internal" href="#defining-window-functions">Defining window functions</a></li>
<li class="toctree-l2"><a class="reference internal" href="#defining-collations-sorting">Defining collations (sorting)</a></li>
<li class="toctree-l2"><a class="reference internal" href="#accessing-results-by-column-name">Accessing results by column name</a></li>
<li class="toctree-l2"><a class="reference internal" href="#type-conversion-into-out-of-database">Type conversion into/out of database</a></li>
<li class="toctree-l2"><a class="reference internal" href="#query-details">Query details</a></li>
<li class="toctree-l2"><a class="reference internal" href="#blob-i-o">Blob I/O</a></li>
<li class="toctree-l2"><a class="reference internal" href="#backup-an-open-database">Backup an open database</a></li>
<li class="toctree-l2"><a class="reference internal" href="#authorizer-control-what-sql-can-do">Authorizer (control what SQL can do)</a></li>
<li class="toctree-l2"><a class="reference internal" href="#progress-handler">Progress handler</a></li>
<li class="toctree-l2"><a class="reference internal" href="#file-control">File Control</a></li>
<li class="toctree-l2"><a class="reference internal" href="#commit-hook">Commit hook</a></li>
<li class="toctree-l2"><a class="reference internal" href="#update-hook">Update hook</a></li>
<li class="toctree-l2"><a class="reference internal" href="#virtual-tables">Virtual tables</a></li>
<li class="toctree-l2"><a class="reference internal" href="#vfs-virtual-file-system">VFS - Virtual File System</a></li>
<li class="toctree-l2"><a class="reference internal" href="#limits">Limits</a></li>
<li class="toctree-l2"><a class="reference internal" href="#shell">Shell</a></li>
<li class="toctree-l2"><a class="reference internal" href="#statistics">Statistics</a></li>
<li class="toctree-l2"><a class="reference internal" href="#tracing">Tracing</a></li>
<li class="toctree-l2"><a class="reference internal" href="#formatting-query-results-table">Formatting query results table</a></li>
<li class="toctree-l2"><a class="reference internal" href="#cleanup">Cleanup</a></li>
</ul>
</li>
<li class="toctree-l1"><a class="reference internal" href="install.html">Installation and customization</a></li>
<li class="toctree-l1"><a class="reference internal" href="extensions.html">Extensions</a></li>
<li class="toctree-l1"><a class="reference internal" href="apsw.html">APSW Module</a></li>
<li class="toctree-l1"><a class="reference internal" href="connection.html">Connections to a database</a></li>
<li class="toctree-l1"><a class="reference internal" href="cursor.html">Cursors (executing SQL)</a></li>
<li class="toctree-l1"><a class="reference internal" href="blob.html">Blob Input/Output</a></li>
<li class="toctree-l1"><a class="reference internal" href="backup.html">Backup</a></li>
<li class="toctree-l1"><a class="reference internal" href="vtable.html">Virtual Tables</a></li>
<li class="toctree-l1"><a class="reference internal" href="vfs.html">Virtual File System (VFS)</a></li>
<li class="toctree-l1"><a class="reference internal" href="shell.html">Shell</a></li>
<li class="toctree-l1"><a class="reference internal" href="bestpractice.html">Best Practice</a></li>
<li class="toctree-l1"><a class="reference internal" href="ext.html">Various interesting and useful bits of functionality</a></li>
<li class="toctree-l1"><a class="reference internal" href="exceptions.html">Exceptions and Errors</a></li>
<li class="toctree-l1"><a class="reference internal" href="execution.html">Execution and tracing</a></li>
<li class="toctree-l1"><a class="reference internal" href="dbapi.html">DBAPI notes</a></li>
<li class="toctree-l1"><a class="reference internal" href="pysqlite.html">sqlite3 module differences</a></li>
<li class="toctree-l1"><a class="reference internal" href="benchmarking.html">Benchmarking</a></li>
<li class="toctree-l1"><a class="reference internal" href="copyright.html">Copyright and License</a></li>
<li class="toctree-l1"><a class="reference internal" href="changes.html">Change History</a></li>
<li class="toctree-l1"><a class="reference internal" href="py-modindex.html">Module Index</a></li>
<li class="toctree-l1"><a class="reference internal" href="genindex.html">Index</a></li>
</ul>
</div>
</div>
</nav>
<section data-toggle="wy-nav-shift" class="wy-nav-content-wrap"><nav class="wy-nav-top" aria-label="Mobile navigation menu" >
<i data-toggle="wy-nav-top" class="fa fa-bars"></i>
<a href="index.html">APSW</a>
</nav>
<div class="wy-nav-content">
<div class="rst-content style-external-links">
<div role="navigation" aria-label="Page navigation">
<ul class="wy-breadcrumbs">
<li><a href="index.html" class="icon icon-home" aria-label="Home"></a></li>
<li class="breadcrumb-item active">Example/Tour</li>
<li class="wy-breadcrumbs-aside">
<a href="_sources/example.rst.txt" rel="nofollow"> View page source</a>
</li>
</ul><div class="rst-breadcrumbs-buttons" role="navigation" aria-label="Sequential page navigation">
<a href="tips.html" class="btn btn-neutral float-left" title="Tips" accesskey="p"><span class="fa fa-arrow-circle-left" aria-hidden="true"></span> Previous</a>
<a href="install.html" class="btn btn-neutral float-right" title="Installation and customization" accesskey="n">Next <span class="fa fa-arrow-circle-right" aria-hidden="true"></span></a>
</div>
<hr/>
</div>
<div role="main" class="document" itemscope="itemscope" itemtype="http://schema.org/Article">
<div itemprop="articleBody">
<section id="example-tour">
<h1>Example/Tour<a class="headerlink" href="#example-tour" title="Link to this heading"></a></h1>
<p>This code demonstrates usage of APSW. It gives you a good overview of
all the things that can be done. Also included is output so you can
see what gets printed when you run the code.</p>
<p>There are also specific examples in the classes, functions,
and attribute documentation.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="ch">#!/usr/bin/env python3</span>
<span class="c1"># This code uses Python's optional typing annotations. You can</span>
<span class="c1"># ignore them and do not need to use them. If you do use them</span>
<span class="c1"># then you must include this future annotations line first.</span>
<span class="kn">from</span> <span class="nn">__future__</span> <span class="kn">import</span> <span class="n">annotations</span>
<span class="kn">from</span> <span class="nn">typing</span> <span class="kn">import</span> <span class="n">Optional</span><span class="p">,</span> <span class="n">Iterator</span><span class="p">,</span> <span class="n">Any</span>
<span class="kn">import</span> <span class="nn">os</span>
<span class="kn">import</span> <span class="nn">sys</span>
<span class="kn">import</span> <span class="nn">time</span>
<span class="kn">import</span> <span class="nn">datetime</span>
<span class="kn">import</span> <span class="nn">apsw</span>
<span class="kn">import</span> <span class="nn">apsw.ext</span>
<span class="kn">import</span> <span class="nn">random</span>
<span class="kn">import</span> <span class="nn">re</span>
<span class="kn">from</span> <span class="nn">pathlib</span> <span class="kn">import</span> <span class="n">Path</span>
</pre></div>
</div>
<section id="checking-apsw-and-sqlite-versions">
<span id="example-version-check"></span><span id="index-0"></span><h2>Checking APSW and SQLite versions<a class="headerlink" href="#checking-apsw-and-sqlite-versions" title="Link to this heading"></a></h2>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># Where the extension module is on the filesystem</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">" Using APSW file"</span><span class="p">,</span> <span class="n">apsw</span><span class="o">.</span><span class="vm">__file__</span><span class="p">)</span>
<span class="c1"># From the extension</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">" APSW version"</span><span class="p">,</span> <span class="n">apsw</span><span class="o">.</span><span class="n">apsw_version</span><span class="p">())</span>
<span class="c1"># From the sqlite header file at APSW compile time</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"SQLite header version"</span><span class="p">,</span> <span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_VERSION_NUMBER</span><span class="p">)</span>
<span class="c1"># The SQLite code running</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">" SQLite lib version"</span><span class="p">,</span> <span class="n">apsw</span><span class="o">.</span><span class="n">sqlite_lib_version</span><span class="p">())</span>
<span class="c1"># If True then SQLite is incorporated into the extension.</span>
<span class="c1"># If False then a shared library is being used, or static linking</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">" Using amalgamation"</span><span class="p">,</span> <span class="n">apsw</span><span class="o">.</span><span class="n">using_amalgamation</span><span class="p">)</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go"> Using APSW file /space/apsw-master/apsw/__init__.cpython-312-x86_64-linux-gnu.so</span>
<span class="go"> APSW version 3.46.0.1</span>
<span class="go">SQLite header version 3046000</span>
<span class="go"> SQLite lib version 3.46.0</span>
<span class="go"> Using amalgamation True</span>
</pre></div>
</div>
</section>
<section id="best-practice">
<span id="example-bestpractice"></span><span id="index-1"></span><h2>Best Practice<a class="headerlink" href="#best-practice" title="Link to this heading"></a></h2>
<p>Ensure SQLite usage prevents common mistakes, and gets best
performance via <a class="reference internal" href="bestpractice.html"><span class="doc">apsw.bestpractice</span></a></p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="kn">import</span> <span class="nn">apsw.bestpractice</span>
<span class="n">apsw</span><span class="o">.</span><span class="n">bestpractice</span><span class="o">.</span><span class="n">apply</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">bestpractice</span><span class="o">.</span><span class="n">recommended</span><span class="p">)</span>
</pre></div>
</div>
</section>
<section id="logging">
<span id="example-logging"></span><span id="index-2"></span><h2>Logging<a class="headerlink" href="#logging" title="Link to this heading"></a></h2>
<p>It is a good idea to get SQLite’s logs as you will get more
information about errors. Best practice also includes this.
<a class="reference internal" href="ext.html#apsw.ext.log_sqlite" title="apsw.ext.log_sqlite"><code class="xref py py-meth docutils literal notranslate"><span class="pre">apsw.ext.log_sqlite()</span></code></a> forwards SQLite’s log messages to the
<a class="reference external" href="https://docs.python.org/3/library/logging.html#module-logging" title="(in Python v3.12)"><code class="xref py py-mod docutils literal notranslate"><span class="pre">logging</span></code></a> module.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">log_sqlite</span><span class="p">()</span>
<span class="c1"># You can also write to SQLite's log</span>
<span class="n">apsw</span><span class="o">.</span><span class="n">log</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_ERROR</span><span class="p">,</span> <span class="s2">"A message from Python"</span><span class="p">)</span>
</pre></div>
</div>
</section>
<section id="opening-the-database">
<span id="example-open-db"></span><span id="index-3"></span><h2>Opening the database<a class="headerlink" href="#opening-the-database" title="Link to this heading"></a></h2>
<p>You open the database by using <a class="reference internal" href="connection.html#apsw.Connection" title="apsw.Connection"><code class="xref py py-class docutils literal notranslate"><span class="pre">Connection</span></code></a></p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># Default will create the database if it doesn't exist</span>
<span class="n">connection</span> <span class="o">=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">Connection</span><span class="p">(</span><span class="s2">"dbfile"</span><span class="p">)</span>
<span class="c1"># Open existing read-only</span>
<span class="n">connection</span> <span class="o">=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">Connection</span><span class="p">(</span><span class="s2">"dbfile"</span><span class="p">,</span> <span class="n">flags</span><span class="o">=</span><span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_OPEN_READONLY</span><span class="p">)</span>
<span class="c1"># Open existing read-write (exception if it doesn't exist)</span>
<span class="n">connection</span> <span class="o">=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">Connection</span><span class="p">(</span><span class="s2">"dbfile"</span><span class="p">,</span> <span class="n">flags</span><span class="o">=</span><span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_OPEN_READWRITE</span><span class="p">)</span>
</pre></div>
</div>
</section>
<section id="executing-sql">
<span id="example-executing-sql"></span><span id="index-4"></span><h2>Executing SQL<a class="headerlink" href="#executing-sql" title="Link to this heading"></a></h2>
<p>Use <a class="reference internal" href="connection.html#apsw.Connection.execute" title="apsw.Connection.execute"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.execute()</span></code></a> to execute SQL</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"create table point(x,y,z)"</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into point values(1, 2, 3)"</span><span class="p">)</span>
<span class="c1"># You can use multiple ; separated statements</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"""</span>
<span class="s2"> insert into point values(4, 5, 6);</span>
<span class="s2"> create table log(timestamp, event);</span>
<span class="s2"> create table foo(a, b, c);</span>
<span class="s2"> create table important(secret, data);</span>
<span class="s2">"""</span><span class="p">)</span>
<span class="c1"># read rows</span>
<span class="k">for</span> <span class="n">row</span> <span class="ow">in</span> <span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"select * from point"</span><span class="p">):</span>
<span class="nb">print</span><span class="p">(</span><span class="n">row</span><span class="p">)</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">(1, 2, 3)</span>
<span class="go">(4, 5, 6)</span>
</pre></div>
</div>
</section>
<section id="why-you-use-bindings-to-provide-values">
<span id="example-why-bindings"></span><span id="index-5"></span><h2>Why you use bindings to provide values<a class="headerlink" href="#why-you-use-bindings-to-provide-values" title="Link to this heading"></a></h2>
<p>It is tempting to compose strings with the values in them, but it is
easy to mangle the query especially if values contain punctuation
and unicode. It is known as <a class="reference external" href="https://en.wikipedia.org/wiki/SQL_injection">SQL injection</a>. Bindings are the
correct way to supply values to queries.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># a simple value</span>
<span class="n">event</span> <span class="o">=</span> <span class="s2">"system started"</span>
<span class="c1"># DO NOT DO THIS</span>
<span class="n">query</span> <span class="o">=</span> <span class="sa">f</span><span class="s2">"insert into log values(0, '</span><span class="si">{</span><span class="w"> </span><span class="n">event</span><span class="w"> </span><span class="si">}</span><span class="s2">')"</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"query:"</span><span class="p">,</span> <span class="n">query</span><span class="p">)</span>
<span class="c1"># BECAUSE ... a bad guy could provide a value like this</span>
<span class="n">event</span> <span class="o">=</span> <span class="s2">"bad guy here') ; drop table important; -- comment"</span>
<span class="c1"># which has effects like this</span>
<span class="n">query</span> <span class="o">=</span> <span class="sa">f</span><span class="s2">"insert into log values(0, '</span><span class="si">{</span><span class="w"> </span><span class="n">event</span><span class="w"> </span><span class="si">}</span><span class="s2">')"</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"bad guy:"</span><span class="p">,</span> <span class="n">query</span><span class="p">)</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">query: insert into log values(0, 'system started')</span>
<span class="go">bad guy: insert into log values(0, 'bad guy here') ; drop table important; -- comment')</span>
</pre></div>
</div>
</section>
<section id="bindings-sequence">
<span id="example-bindings-sequence"></span><span id="index-6"></span><h2>Bindings (sequence)<a class="headerlink" href="#bindings-sequence" title="Link to this heading"></a></h2>
<p>Bindings can be provided as a sequence such as with
a tuple or list. Use <strong>?</strong> to show where the values go.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="n">query</span> <span class="o">=</span> <span class="s2">"insert into log values(?, ?)"</span>
<span class="n">data</span> <span class="o">=</span> <span class="p">(</span><span class="mi">7</span><span class="p">,</span> <span class="s2">"transmission started"</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="n">query</span><span class="p">,</span> <span class="n">data</span><span class="p">)</span>
<span class="c1"># You can also use numbers after the ? to select</span>
<span class="c1"># values from the sequence. Note that numbering</span>
<span class="c1"># starts at 1</span>
<span class="n">query</span> <span class="o">=</span> <span class="s2">"select ?1, ?3, ?2"</span>
<span class="n">data</span> <span class="o">=</span> <span class="p">(</span><span class="s2">"alpha"</span><span class="p">,</span> <span class="s2">"beta"</span><span class="p">,</span> <span class="s2">"gamma"</span><span class="p">)</span>
<span class="k">for</span> <span class="n">row</span> <span class="ow">in</span> <span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="n">query</span><span class="p">,</span> <span class="n">data</span><span class="p">):</span>
<span class="nb">print</span><span class="p">(</span><span class="n">row</span><span class="p">)</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">('alpha', 'gamma', 'beta')</span>
</pre></div>
</div>
</section>
<section id="bindings-dict">
<span id="example-bindings-dict"></span><span id="index-7"></span><h2>Bindings (dict)<a class="headerlink" href="#bindings-dict" title="Link to this heading"></a></h2>
<p>You can also supply bindings with a dictionary. Use <strong>:NAME</strong>,
<strong>@NAME</strong>, or <strong>$NAME</strong>, to provide the key name in the query.
Names are case sensitive.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="n">query</span> <span class="o">=</span> <span class="s2">"insert into point values(:x, @Y, $z)"</span>
<span class="n">data</span> <span class="o">=</span> <span class="p">{</span><span class="s2">"x"</span><span class="p">:</span> <span class="mi">7</span><span class="p">,</span> <span class="s2">"Y"</span><span class="p">:</span> <span class="mi">8</span><span class="p">,</span> <span class="s2">"z"</span><span class="p">:</span> <span class="mi">9</span><span class="p">}</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="n">query</span><span class="p">,</span> <span class="n">data</span><span class="p">)</span>
</pre></div>
</div>
</section>
<section id="transactions">
<span id="example-transaction"></span><span id="index-8"></span><h2>Transactions<a class="headerlink" href="#transactions" title="Link to this heading"></a></h2>
<p>By default each statement is its own transaction. A transaction
finishes by flushing data to storage and waiting for the operating
system to confirm it is permanently there (ie will survive a power
failure) which takes a while.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># 3 separate transactions</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into point values(2, 2, 2)"</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into point values(3, 3, 3)"</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into point values(4, 4, 4)"</span><span class="p">)</span>
<span class="c1"># You can use BEGIN / COMMIT to manually make a transaction</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"BEGIN"</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into point values(2, 2, 2)"</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into point values(3, 3, 3)"</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into point values(4, 4, 4)"</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"COMMIT"</span><span class="p">)</span>
<span class="c1"># Or use `with` that does it automatically</span>
<span class="k">with</span> <span class="n">connection</span><span class="p">:</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into point values(2, 2, 2)"</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into point values(3, 3, 3)"</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into point values(4, 4, 4)"</span><span class="p">)</span>
<span class="c1"># Nested transactions are supported</span>
<span class="k">with</span> <span class="n">connection</span><span class="p">:</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into point values(2, 2, 2)"</span><span class="p">)</span>
<span class="k">with</span> <span class="n">connection</span><span class="p">:</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into point values(3, 3, 3)"</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into point values(4, 4, 4)"</span><span class="p">)</span>
</pre></div>
</div>
</section>
<section id="executemany">
<span id="example-executemany"></span><span id="index-9"></span><h2>executemany<a class="headerlink" href="#executemany" title="Link to this heading"></a></h2>
<p>You can execute the same SQL against a sequence using
<a class="reference internal" href="connection.html#apsw.Connection.executemany" title="apsw.Connection.executemany"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.executemany()</span></code></a></p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="n">data</span> <span class="o">=</span> <span class="p">(</span>
<span class="p">(</span><span class="mi">1</span><span class="p">,</span> <span class="mi">1</span><span class="p">,</span> <span class="mi">1</span><span class="p">),</span>
<span class="p">(</span><span class="mi">2</span><span class="p">,</span> <span class="mi">2</span><span class="p">,</span> <span class="mi">2</span><span class="p">),</span>
<span class="p">(</span><span class="mi">3</span><span class="p">,</span> <span class="mi">3</span><span class="p">,</span> <span class="mi">3</span><span class="p">),</span>
<span class="p">(</span><span class="mi">4</span><span class="p">,</span> <span class="mi">4</span><span class="p">,</span> <span class="mi">4</span><span class="p">),</span>
<span class="p">(</span><span class="mi">5</span><span class="p">,</span> <span class="mi">5</span><span class="p">,</span> <span class="mi">5</span><span class="p">),</span>
<span class="p">)</span>
<span class="n">query</span> <span class="o">=</span> <span class="s2">"insert into point values(?,?,?)"</span>
<span class="c1"># we do it in a transaction</span>
<span class="k">with</span> <span class="n">connection</span><span class="p">:</span>
<span class="c1"># the query is run for each item in data</span>
<span class="n">connection</span><span class="o">.</span><span class="n">executemany</span><span class="p">(</span><span class="n">query</span><span class="p">,</span> <span class="n">data</span><span class="p">)</span>
</pre></div>
</div>
</section>
<section id="pragmas">
<span id="example-pragma"></span><span id="index-10"></span><h2>Pragmas<a class="headerlink" href="#pragmas" title="Link to this heading"></a></h2>
<p>SQLite has a <a class="reference external" href="https://www.sqlite.org/pragma.html">wide variety of pragmas</a> to control
the database configuration and library behaviour. See the <a class="reference internal" href="tips.html"><span class="doc">Tips</span></a> for maintaining
your schema.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># WAL mode is good for write performance</span>
<span class="n">connection</span><span class="o">.</span><span class="n">pragma</span><span class="p">(</span><span class="s2">"journal_mode"</span><span class="p">,</span> <span class="s2">"wal"</span><span class="p">)</span>
<span class="c1"># Foreign keys are off by default, so turn them on</span>
<span class="n">connection</span><span class="o">.</span><span class="n">pragma</span><span class="p">(</span><span class="s2">"foreign_keys"</span><span class="p">,</span> <span class="kc">True</span><span class="p">)</span>
<span class="c1"># You can use this to see if any other connection (including other processes) has</span>
<span class="c1"># changed the database</span>
<span class="n">connection</span><span class="o">.</span><span class="n">pragma</span><span class="p">(</span><span class="s2">"data_version"</span><span class="p">)</span>
<span class="c1"># Useful at startup to detect some database corruption</span>
<span class="n">check</span> <span class="o">=</span> <span class="n">connection</span><span class="o">.</span><span class="n">pragma</span><span class="p">(</span><span class="s2">"integrity_check"</span><span class="p">)</span>
<span class="k">if</span> <span class="n">check</span> <span class="o">!=</span> <span class="s2">"ok"</span><span class="p">:</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"Integrity check errors"</span><span class="p">,</span> <span class="n">check</span><span class="p">)</span>
</pre></div>
</div>
</section>
<section id="tracing-execution">
<span id="example-exectrace"></span><span id="index-11"></span><h2>Tracing execution<a class="headerlink" href="#tracing-execution" title="Link to this heading"></a></h2>
<p>You can trace execution of SQL statements. See <a class="reference internal" href="execution.html#tracing"><span class="std std-ref">more about
tracing</span></a>.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="k">def</span> <span class="nf">my_tracer</span><span class="p">(</span><span class="n">cursor</span><span class="p">:</span> <span class="n">apsw</span><span class="o">.</span><span class="n">Cursor</span><span class="p">,</span> <span class="n">statement</span><span class="p">:</span> <span class="nb">str</span><span class="p">,</span> <span class="n">bindings</span><span class="p">:</span> <span class="n">Optional</span><span class="p">[</span><span class="n">apsw</span><span class="o">.</span><span class="n">Bindings</span><span class="p">])</span> <span class="o">-></span> <span class="nb">bool</span><span class="p">:</span>
<span class="s2">"Called just before executing each statement"</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"SQL:"</span><span class="p">,</span> <span class="n">statement</span><span class="o">.</span><span class="n">strip</span><span class="p">())</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"Bindings:"</span><span class="p">,</span> <span class="n">bindings</span><span class="p">)</span>
<span class="k">return</span> <span class="kc">True</span> <span class="c1"># if you return False then execution is aborted</span>
<span class="c1"># you can trace a single cursor</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="n">cursor</span><span class="o">.</span><span class="n">exec_trace</span> <span class="o">=</span> <span class="n">my_tracer</span>
<span class="n">cursor</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span>
<span class="w"> </span><span class="sd">"""</span>
<span class="sd"> drop table if exists bar;</span>
<span class="sd"> create table bar(x,y,z);</span>
<span class="sd"> select * from point where x=?;</span>
<span class="sd"> """</span><span class="p">,</span>
<span class="p">(</span><span class="mi">3</span><span class="p">,),</span>
<span class="p">)</span>
<span class="c1"># if set on a connection then all cursors are traced</span>
<span class="n">connection</span><span class="o">.</span><span class="n">exec_trace</span> <span class="o">=</span> <span class="n">my_tracer</span>
<span class="c1"># and clearing it</span>
<span class="n">connection</span><span class="o">.</span><span class="n">exec_trace</span> <span class="o">=</span> <span class="kc">None</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">SQL: drop table if exists bar;</span>
<span class="go">Bindings: ()</span>
<span class="go">SQL: create table bar(x,y,z);</span>
<span class="go">Bindings: ()</span>
<span class="go">SQL: select * from point where x=?;</span>
<span class="go">Bindings: (3,)</span>
</pre></div>
</div>
</section>
<section id="tracing-returned-rows">
<span id="example-rowtrace"></span><span id="index-12"></span><h2>Tracing returned rows<a class="headerlink" href="#tracing-returned-rows" title="Link to this heading"></a></h2>
<p>You can trace returned rows, including modifying what is returned or
skipping it completely. See <a class="reference internal" href="execution.html#tracing"><span class="std std-ref">more about tracing</span></a>.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="k">def</span> <span class="nf">row_tracer</span><span class="p">(</span><span class="n">cursor</span><span class="p">:</span> <span class="n">apsw</span><span class="o">.</span><span class="n">Cursor</span><span class="p">,</span> <span class="n">row</span><span class="p">:</span> <span class="n">apsw</span><span class="o">.</span><span class="n">SQLiteValues</span><span class="p">)</span> <span class="o">-></span> <span class="n">apsw</span><span class="o">.</span><span class="n">SQLiteValues</span><span class="p">:</span>
<span class="w"> </span><span class="sd">"""Called with each row of results before they are handed off. You can return None to</span>
<span class="sd"> cause the row to be skipped or a different set of values to return"""</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"Row:"</span><span class="p">,</span> <span class="n">row</span><span class="p">)</span>
<span class="k">return</span> <span class="n">row</span>
<span class="c1"># you can trace a single cursor</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="n">cursor</span><span class="o">.</span><span class="n">row_trace</span> <span class="o">=</span> <span class="n">row_tracer</span>
<span class="k">for</span> <span class="n">row</span> <span class="ow">in</span> <span class="n">cursor</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"select x,y from point where x>4"</span><span class="p">):</span>
<span class="k">pass</span>
<span class="c1"># if set on a connection then all cursors are traced</span>
<span class="n">connection</span><span class="o">.</span><span class="n">row_trace</span> <span class="o">=</span> <span class="n">row_tracer</span>
<span class="c1"># and clearing it</span>
<span class="n">connection</span><span class="o">.</span><span class="n">row_trace</span> <span class="o">=</span> <span class="kc">None</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">Row: (7, 8)</span>
<span class="go">Row: (5, 5)</span>
</pre></div>
</div>
</section>
<section id="defining-scalar-functions">
<span id="example-scalar"></span><span id="index-13"></span><h2>Defining scalar functions<a class="headerlink" href="#defining-scalar-functions" title="Link to this heading"></a></h2>
<p>Scalar functions take one or more values and return one value. They
are registered by calling <a class="reference internal" href="connection.html#apsw.Connection.create_scalar_function" title="apsw.Connection.create_scalar_function"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.create_scalar_function()</span></code></a>.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="k">def</span> <span class="nf">ilove7</span><span class="p">(</span><span class="o">*</span><span class="n">args</span><span class="p">:</span> <span class="n">apsw</span><span class="o">.</span><span class="n">SQLiteValue</span><span class="p">)</span> <span class="o">-></span> <span class="nb">int</span><span class="p">:</span>
<span class="s2">"A scalar function"</span>
<span class="nb">print</span><span class="p">(</span><span class="sa">f</span><span class="s2">"ilove7 got </span><span class="si">{</span><span class="w"> </span><span class="n">args</span><span class="w"> </span><span class="si">}</span><span class="s2"> but I love 7"</span><span class="p">)</span>
<span class="k">return</span> <span class="mi">7</span>
<span class="n">connection</span><span class="o">.</span><span class="n">create_scalar_function</span><span class="p">(</span><span class="s2">"seven"</span><span class="p">,</span> <span class="n">ilove7</span><span class="p">)</span>
<span class="k">for</span> <span class="n">row</span> <span class="ow">in</span> <span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"select seven(x,y) from point where x>4"</span><span class="p">):</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"row"</span><span class="p">,</span> <span class="n">row</span><span class="p">)</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">ilove7 got (7, 8) but I love 7</span>
<span class="go">row (7,)</span>
<span class="go">ilove7 got (5, 5) but I love 7</span>
<span class="go">row (7,)</span>
</pre></div>
</div>
</section>
<section id="defining-aggregate-functions">
<span id="example-aggregate"></span><span id="index-14"></span><h2>Defining aggregate functions<a class="headerlink" href="#defining-aggregate-functions" title="Link to this heading"></a></h2>
<p>Aggregate functions are called multiple times with matching rows,
and then provide a final value. An example is calculating an
average. They are registered by calling
<a class="reference internal" href="connection.html#apsw.Connection.create_aggregate_function" title="apsw.Connection.create_aggregate_function"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.create_aggregate_function()</span></code></a>.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="k">class</span> <span class="nc">longest</span><span class="p">:</span>
<span class="c1"># Find which value when represented as a string is</span>
<span class="c1"># the longest</span>
<span class="k">def</span> <span class="fm">__init__</span><span class="p">(</span><span class="bp">self</span><span class="p">)</span> <span class="o">-></span> <span class="kc">None</span><span class="p">:</span>
<span class="bp">self</span><span class="o">.</span><span class="n">longest</span> <span class="o">=</span> <span class="s2">""</span>
<span class="k">def</span> <span class="nf">step</span><span class="p">(</span><span class="bp">self</span><span class="p">,</span> <span class="o">*</span><span class="n">args</span><span class="p">:</span> <span class="n">apsw</span><span class="o">.</span><span class="n">SQLiteValue</span><span class="p">)</span> <span class="o">-></span> <span class="kc">None</span><span class="p">:</span>
<span class="c1"># Called with each matching row</span>
<span class="k">for</span> <span class="n">arg</span> <span class="ow">in</span> <span class="n">args</span><span class="p">:</span>
<span class="k">if</span> <span class="nb">len</span><span class="p">(</span><span class="nb">str</span><span class="p">(</span><span class="n">arg</span><span class="p">))</span> <span class="o">></span> <span class="nb">len</span><span class="p">(</span><span class="bp">self</span><span class="o">.</span><span class="n">longest</span><span class="p">):</span>
<span class="bp">self</span><span class="o">.</span><span class="n">longest</span> <span class="o">=</span> <span class="nb">str</span><span class="p">(</span><span class="n">arg</span><span class="p">)</span>
<span class="k">def</span> <span class="nf">final</span><span class="p">(</span><span class="bp">self</span><span class="p">)</span> <span class="o">-></span> <span class="nb">str</span><span class="p">:</span>
<span class="c1"># Called at the very end</span>
<span class="k">return</span> <span class="bp">self</span><span class="o">.</span><span class="n">longest</span>
<span class="n">connection</span><span class="o">.</span><span class="n">create_aggregate_function</span><span class="p">(</span><span class="s2">"longest"</span><span class="p">,</span> <span class="n">longest</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"select longest(event) from log"</span><span class="p">)</span><span class="o">.</span><span class="n">get</span><span class="p">)</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">transmission started</span>
</pre></div>
</div>
</section>
<section id="defining-window-functions">
<span id="example-window"></span><span id="index-15"></span><h2>Defining window functions<a class="headerlink" href="#defining-window-functions" title="Link to this heading"></a></h2>
<p>Window functions input values come from a “window” around a row of
interest. Four methods are called as the window moves to add,
remove, get the current value, and finalize.</p>
<p>An example is calculating an average of values in the window to
compare to the row. They are registered by calling
<a class="reference internal" href="connection.html#apsw.Connection.create_window_function" title="apsw.Connection.create_window_function"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.create_window_function()</span></code></a>.</p>
<p>This is the Python equivalent to the C based example in the <a class="reference external" href="https://www.sqlite.org/windowfunctions.html#user_defined_aggregate_window_functions">SQLite
documentation</a></p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="k">class</span> <span class="nc">SumInt</span><span class="p">:</span>
<span class="k">def</span> <span class="fm">__init__</span><span class="p">(</span><span class="bp">self</span><span class="p">):</span>
<span class="bp">self</span><span class="o">.</span><span class="n">v</span> <span class="o">=</span> <span class="mi">0</span>
<span class="k">def</span> <span class="nf">step</span><span class="p">(</span><span class="bp">self</span><span class="p">,</span> <span class="n">arg</span><span class="p">):</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"step"</span><span class="p">,</span> <span class="n">arg</span><span class="p">)</span>
<span class="bp">self</span><span class="o">.</span><span class="n">v</span> <span class="o">+=</span> <span class="n">arg</span>
<span class="k">def</span> <span class="nf">inverse</span><span class="p">(</span><span class="bp">self</span><span class="p">,</span> <span class="n">arg</span><span class="p">):</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"inverse"</span><span class="p">,</span> <span class="n">arg</span><span class="p">)</span>
<span class="bp">self</span><span class="o">.</span><span class="n">v</span> <span class="o">-=</span> <span class="n">arg</span>
<span class="k">def</span> <span class="nf">final</span><span class="p">(</span><span class="bp">self</span><span class="p">):</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"final"</span><span class="p">,</span> <span class="bp">self</span><span class="o">.</span><span class="n">v</span><span class="p">)</span>
<span class="k">return</span> <span class="bp">self</span><span class="o">.</span><span class="n">v</span>
<span class="k">def</span> <span class="nf">value</span><span class="p">(</span><span class="bp">self</span><span class="p">):</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"value"</span><span class="p">,</span> <span class="bp">self</span><span class="o">.</span><span class="n">v</span><span class="p">)</span>
<span class="k">return</span> <span class="bp">self</span><span class="o">.</span><span class="n">v</span>
<span class="n">connection</span><span class="o">.</span><span class="n">create_window_function</span><span class="p">(</span><span class="s2">"sumint"</span><span class="p">,</span> <span class="n">SumInt</span><span class="p">)</span>
<span class="k">for</span> <span class="n">row</span> <span class="ow">in</span> <span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"""</span>
<span class="s2"> CREATE TABLE t3(x, y);</span>
<span class="s2"> INSERT INTO t3 VALUES('a', 4),</span>
<span class="s2"> ('b', 5),</span>
<span class="s2"> ('c', 3),</span>
<span class="s2"> ('d', 8),</span>
<span class="s2"> ('e', 1);</span>
<span class="s2"> -- Use the window function</span>
<span class="s2"> SELECT x, sumint(y) OVER (</span>
<span class="s2"> ORDER BY x ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING</span>
<span class="s2"> ) AS sum_y</span>
<span class="s2"> FROM t3 ORDER BY x;</span>
<span class="s2"> """</span><span class="p">):</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"ROW"</span><span class="p">,</span> <span class="n">row</span><span class="p">)</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">step 4</span>
<span class="go">step 5</span>
<span class="go">value 9</span>
<span class="go">ROW ('a', 9)</span>
<span class="go">step 3</span>
<span class="go">value 12</span>
<span class="go">ROW ('b', 12)</span>
<span class="go">inverse 4</span>
<span class="go">step 8</span>
<span class="go">value 16</span>
<span class="go">ROW ('c', 16)</span>
<span class="go">inverse 5</span>
<span class="go">step 1</span>
<span class="go">value 12</span>
<span class="go">ROW ('d', 12)</span>
<span class="go">inverse 3</span>
<span class="go">value 9</span>
<span class="go">ROW ('e', 9)</span>
<span class="go">final 9</span>
</pre></div>
</div>
</section>
<section id="defining-collations-sorting">
<span id="example-collation"></span><span id="index-16"></span><h2>Defining collations (sorting)<a class="headerlink" href="#defining-collations-sorting" title="Link to this heading"></a></h2>
<p>How you sort can depend on the languages or values involved. You
register a collation by calling <a class="reference internal" href="connection.html#apsw.Connection.create_collation" title="apsw.Connection.create_collation"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.create_collation()</span></code></a>.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># This example sorting mechanisms understands some text followed by a</span>
<span class="c1"># number and ensures the number portion gets sorted correctly</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"create table names(name)"</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">executemany</span><span class="p">(</span>
<span class="s2">"insert into names values(?)"</span><span class="p">,</span>
<span class="p">(</span>
<span class="p">(</span><span class="s2">"file1"</span><span class="p">,),</span>
<span class="p">(</span><span class="s2">"file7"</span><span class="p">,),</span>
<span class="p">(</span><span class="s2">"file17"</span><span class="p">,),</span>
<span class="p">(</span><span class="s2">"file20"</span><span class="p">,),</span>
<span class="p">(</span><span class="s2">"file3"</span><span class="p">,),</span>
<span class="p">),</span>
<span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"Standard sorting"</span><span class="p">)</span>
<span class="k">for</span> <span class="n">row</span> <span class="ow">in</span> <span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"select * from names order by name"</span><span class="p">):</span>
<span class="nb">print</span><span class="p">(</span><span class="n">row</span><span class="p">)</span>
<span class="k">def</span> <span class="nf">str_num_collate</span><span class="p">(</span><span class="n">s1</span><span class="p">:</span> <span class="n">apsw</span><span class="o">.</span><span class="n">SQLiteValue</span><span class="p">,</span> <span class="n">s2</span><span class="p">:</span> <span class="n">apsw</span><span class="o">.</span><span class="n">SQLiteValue</span><span class="p">)</span> <span class="o">-></span> <span class="nb">int</span><span class="p">:</span>
<span class="c1"># return -1 if s1<s2, +1 if s1>s2 else 0 for equal</span>
<span class="k">def</span> <span class="nf">parts</span><span class="p">(</span><span class="n">s</span><span class="p">:</span> <span class="nb">str</span><span class="p">)</span> <span class="o">-></span> <span class="nb">list</span><span class="p">:</span>
<span class="s2">"Converts str into list of alternating str and int parts"</span>
<span class="k">return</span> <span class="p">[</span><span class="nb">int</span><span class="p">(</span><span class="n">v</span><span class="p">)</span> <span class="k">if</span> <span class="n">v</span><span class="o">.</span><span class="n">isdigit</span><span class="p">()</span> <span class="k">else</span> <span class="n">v</span> <span class="k">for</span> <span class="n">v</span> <span class="ow">in</span> <span class="n">re</span><span class="o">.</span><span class="n">split</span><span class="p">(</span><span class="sa">r</span><span class="s2">"(\d+)"</span><span class="p">,</span> <span class="n">s</span><span class="p">)]</span>
<span class="n">ps1</span> <span class="o">=</span> <span class="n">parts</span><span class="p">(</span><span class="nb">str</span><span class="p">(</span><span class="n">s1</span><span class="p">))</span>
<span class="n">ps2</span> <span class="o">=</span> <span class="n">parts</span><span class="p">(</span><span class="nb">str</span><span class="p">(</span><span class="n">s2</span><span class="p">))</span>
<span class="c1"># compare</span>
<span class="k">if</span> <span class="n">ps1</span> <span class="o"><</span> <span class="n">ps2</span><span class="p">:</span>
<span class="k">return</span> <span class="o">-</span><span class="mi">1</span>
<span class="k">if</span> <span class="n">ps1</span> <span class="o">></span> <span class="n">ps2</span><span class="p">:</span>
<span class="k">return</span> <span class="mi">1</span>
<span class="k">return</span> <span class="mi">0</span>
<span class="n">connection</span><span class="o">.</span><span class="n">create_collation</span><span class="p">(</span><span class="s2">"strnum"</span><span class="p">,</span> <span class="n">str_num_collate</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"</span><span class="se">\n</span><span class="s2">Using strnum"</span><span class="p">)</span>
<span class="k">for</span> <span class="n">row</span> <span class="ow">in</span> <span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"select * from names order by name collate strnum"</span><span class="p">):</span>
<span class="nb">print</span><span class="p">(</span><span class="n">row</span><span class="p">)</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">Standard sorting</span>
<span class="go">('file1',)</span>
<span class="go">('file17',)</span>
<span class="go">('file20',)</span>
<span class="go">('file3',)</span>
<span class="go">('file7',)</span>
<span class="go">Using strnum</span>
<span class="go">('file1',)</span>
<span class="go">('file3',)</span>
<span class="go">('file7',)</span>
<span class="go">('file17',)</span>
<span class="go">('file20',)</span>
</pre></div>
</div>
</section>
<section id="accessing-results-by-column-name">
<span id="example-colnames"></span><span id="index-17"></span><h2>Accessing results by column name<a class="headerlink" href="#accessing-results-by-column-name" title="Link to this heading"></a></h2>
<p>You can access results by column name using <a class="reference external" href="https://docs.python.org/3/library/dataclasses.html#module-dataclasses" title="(in Python v3.12)"><code class="xref py py-mod docutils literal notranslate"><span class="pre">dataclasses</span></code></a>.
APSW provides <a class="reference internal" href="ext.html#apsw.ext.DataClassRowFactory" title="apsw.ext.DataClassRowFactory"><code class="xref py py-class docutils literal notranslate"><span class="pre">apsw.ext.DataClassRowFactory</span></code></a> for names.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="kn">import</span> <span class="nn">apsw.ext</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"""</span>
<span class="s2"> create table books(id, title, author, year);</span>
<span class="s2"> insert into books values(7, 'Animal Farm', 'George Orwell', 1945);</span>
<span class="s2"> insert into books values(37, 'The Picture of Dorian Gray', 'Oscar Wilde', 1890);</span>
<span class="s2"> """</span><span class="p">)</span>
<span class="c1"># Normally you use column numbers</span>
<span class="k">for</span> <span class="n">row</span> <span class="ow">in</span> <span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"select title, id, year from books where author=?"</span><span class="p">,</span> <span class="p">(</span><span class="s2">"Oscar Wilde"</span><span class="p">,)):</span>
<span class="c1"># this is very fragile</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"title"</span><span class="p">,</span> <span class="n">row</span><span class="p">[</span><span class="mi">0</span><span class="p">])</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"id"</span><span class="p">,</span> <span class="n">row</span><span class="p">[</span><span class="mi">1</span><span class="p">])</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"year"</span><span class="p">,</span> <span class="n">row</span><span class="p">[</span><span class="mi">2</span><span class="p">])</span>
<span class="c1"># Turn on dataclasses - frozen makes them read-only</span>
<span class="n">connection</span><span class="o">.</span><span class="n">row_trace</span> <span class="o">=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">DataClassRowFactory</span><span class="p">(</span><span class="n">dataclass_kwargs</span><span class="o">=</span><span class="p">{</span><span class="s2">"frozen"</span><span class="p">:</span> <span class="kc">True</span><span class="p">})</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"</span><span class="se">\n</span><span class="s2">Now with dataclasses</span><span class="se">\n</span><span class="s2">"</span><span class="p">)</span>
<span class="c1"># Same query - note using AS to set column name</span>
<span class="k">for</span> <span class="n">row</span> <span class="ow">in</span> <span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span>
<span class="w"> </span><span class="sd">"""SELECT title,</span>
<span class="sd"> id AS book_id,</span>
<span class="sd"> year AS book_year</span>
<span class="sd"> FROM books WHERE author = ?"""</span><span class="p">,</span>
<span class="p">(</span><span class="s2">"Oscar Wilde"</span><span class="p">,),</span>
<span class="p">):</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"title"</span><span class="p">,</span> <span class="n">row</span><span class="o">.</span><span class="n">title</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"id"</span><span class="p">,</span> <span class="n">row</span><span class="o">.</span><span class="n">book_id</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"year"</span><span class="p">,</span> <span class="n">row</span><span class="o">.</span><span class="n">book_year</span><span class="p">)</span>
<span class="c1"># clear</span>
<span class="n">connection</span><span class="o">.</span><span class="n">row_trace</span> <span class="o">=</span> <span class="kc">None</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">title The Picture of Dorian Gray</span>
<span class="go">id 37</span>
<span class="go">year 1890</span>
<span class="go">Now with dataclasses</span>
<span class="go">title The Picture of Dorian Gray</span>
<span class="go">id 37</span>
<span class="go">year 1890</span>
</pre></div>
</div>
</section>
<section id="type-conversion-into-out-of-database">
<span id="example-type-conversion"></span><span id="index-18"></span><h2>Type conversion into/out of database<a class="headerlink" href="#type-conversion-into-out-of-database" title="Link to this heading"></a></h2>
<p>You can use <a class="reference internal" href="ext.html#apsw.ext.TypesConverterCursorFactory" title="apsw.ext.TypesConverterCursorFactory"><code class="xref py py-class docutils literal notranslate"><span class="pre">apsw.ext.TypesConverterCursorFactory</span></code></a> to do
conversion, both for types you define and for other types.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="kn">import</span> <span class="nn">apsw.ext</span>
<span class="n">registrar</span> <span class="o">=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">TypesConverterCursorFactory</span><span class="p">()</span>
<span class="n">connection</span><span class="o">.</span><span class="n">cursor_factory</span> <span class="o">=</span> <span class="n">registrar</span>
<span class="c1"># A type we define - deriving from SQLiteTypeAdapter automatically registers conversion</span>
<span class="c1"># to a SQLite value</span>
<span class="k">class</span> <span class="nc">Point</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">SQLiteTypeAdapter</span><span class="p">):</span>
<span class="k">def</span> <span class="fm">__init__</span><span class="p">(</span><span class="bp">self</span><span class="p">,</span> <span class="n">x</span><span class="p">,</span> <span class="n">y</span><span class="p">):</span>
<span class="bp">self</span><span class="o">.</span><span class="n">x</span> <span class="o">=</span> <span class="n">x</span>
<span class="bp">self</span><span class="o">.</span><span class="n">y</span> <span class="o">=</span> <span class="n">y</span>
<span class="k">def</span> <span class="fm">__repr__</span><span class="p">(</span><span class="bp">self</span><span class="p">)</span> <span class="o">-></span> <span class="nb">str</span><span class="p">:</span>
<span class="k">return</span> <span class="sa">f</span><span class="s2">"Point(</span><span class="si">{</span><span class="w"> </span><span class="bp">self</span><span class="o">.</span><span class="n">x</span><span class="w"> </span><span class="si">}</span><span class="s2">, </span><span class="si">{</span><span class="w"> </span><span class="bp">self</span><span class="o">.</span><span class="n">y</span><span class="w"> </span><span class="si">}</span><span class="s2">)"</span>
<span class="k">def</span> <span class="fm">__eq__</span><span class="p">(</span><span class="bp">self</span><span class="p">,</span> <span class="n">other</span><span class="p">:</span> <span class="nb">object</span><span class="p">)</span> <span class="o">-></span> <span class="nb">bool</span><span class="p">:</span>
<span class="k">return</span> <span class="nb">isinstance</span><span class="p">(</span><span class="n">other</span><span class="p">,</span> <span class="nb">type</span><span class="p">(</span><span class="bp">self</span><span class="p">))</span> <span class="ow">and</span> <span class="bp">self</span><span class="o">.</span><span class="n">x</span> <span class="o">==</span> <span class="n">other</span><span class="o">.</span><span class="n">x</span> <span class="ow">and</span> <span class="bp">self</span><span class="o">.</span><span class="n">y</span> <span class="o">==</span> <span class="n">other</span><span class="o">.</span><span class="n">y</span>
<span class="k">def</span> <span class="nf">to_sqlite_value</span><span class="p">(</span><span class="bp">self</span><span class="p">)</span> <span class="o">-></span> <span class="nb">str</span><span class="p">:</span>
<span class="c1"># called to convert Point into something SQLite supports</span>
<span class="k">return</span> <span class="sa">f</span><span class="s2">"</span><span class="si">{</span><span class="w"> </span><span class="bp">self</span><span class="o">.</span><span class="n">x</span><span class="w"> </span><span class="si">}</span><span class="s2">;</span><span class="si">{</span><span class="w"> </span><span class="bp">self</span><span class="o">.</span><span class="n">y</span><span class="w"> </span><span class="si">}</span><span class="s2">"</span>
<span class="c1"># This converter will be registered</span>
<span class="nd">@classmethod</span>
<span class="k">def</span> <span class="nf">convert_from_sqlite</span><span class="p">(</span><span class="bp">cls</span><span class="p">,</span> <span class="n">value</span><span class="p">:</span> <span class="nb">str</span><span class="p">)</span> <span class="o">-></span> <span class="n">Point</span><span class="p">:</span>
<span class="k">return</span> <span class="bp">cls</span><span class="p">(</span><span class="o">*</span><span class="p">(</span><span class="nb">float</span><span class="p">(</span><span class="n">part</span><span class="p">)</span> <span class="k">for</span> <span class="n">part</span> <span class="ow">in</span> <span class="n">value</span><span class="o">.</span><span class="n">split</span><span class="p">(</span><span class="s2">";"</span><span class="p">)))</span>
<span class="c1"># Existing types</span>
<span class="k">def</span> <span class="nf">complex_to_sqlite_value</span><span class="p">(</span><span class="n">c</span><span class="p">:</span> <span class="nb">complex</span><span class="p">)</span> <span class="o">-></span> <span class="nb">str</span><span class="p">:</span>
<span class="k">return</span> <span class="sa">f</span><span class="s2">"</span><span class="si">{</span><span class="w"> </span><span class="n">c</span><span class="o">.</span><span class="n">real</span><span class="w"> </span><span class="si">}</span><span class="s2">+</span><span class="si">{</span><span class="w"> </span><span class="n">c</span><span class="o">.</span><span class="n">imag</span><span class="w"> </span><span class="si">}</span><span class="s2">"</span>
<span class="k">def</span> <span class="nf">datetime_to_sqlite_value</span><span class="p">(</span><span class="n">dt</span><span class="p">:</span> <span class="n">datetime</span><span class="o">.</span><span class="n">datetime</span><span class="p">)</span> <span class="o">-></span> <span class="nb">float</span><span class="p">:</span>
<span class="c1"># Represent as floating point UTC value no matter</span>
<span class="c1"># what timezone is used. Also consider other</span>
<span class="c1"># formats like ISO8601.</span>
<span class="k">return</span> <span class="n">dt</span><span class="o">.</span><span class="n">timestamp</span><span class="p">()</span>
<span class="c1"># ... require manual registration</span>
<span class="n">registrar</span><span class="o">.</span><span class="n">register_adapter</span><span class="p">(</span><span class="nb">complex</span><span class="p">,</span> <span class="n">complex_to_sqlite_value</span><span class="p">)</span>
<span class="n">registrar</span><span class="o">.</span><span class="n">register_adapter</span><span class="p">(</span><span class="n">datetime</span><span class="o">.</span><span class="n">datetime</span><span class="p">,</span> <span class="n">datetime_to_sqlite_value</span><span class="p">)</span>
<span class="c1"># conversion from a SQLite value requires registration</span>
<span class="n">registrar</span><span class="o">.</span><span class="n">register_converter</span><span class="p">(</span><span class="s2">"POINT"</span><span class="p">,</span> <span class="n">Point</span><span class="o">.</span><span class="n">convert_from_sqlite</span><span class="p">)</span>
<span class="c1"># ... and for stdlib types</span>
<span class="k">def</span> <span class="nf">sqlite_to_complex</span><span class="p">(</span><span class="n">v</span><span class="p">:</span> <span class="nb">str</span><span class="p">)</span> <span class="o">-></span> <span class="nb">complex</span><span class="p">:</span>
<span class="k">return</span> <span class="nb">complex</span><span class="p">(</span><span class="o">*</span><span class="p">(</span><span class="nb">float</span><span class="p">(</span><span class="n">part</span><span class="p">)</span> <span class="k">for</span> <span class="n">part</span> <span class="ow">in</span> <span class="n">v</span><span class="o">.</span><span class="n">split</span><span class="p">(</span><span class="s2">"+"</span><span class="p">)))</span>
<span class="k">def</span> <span class="nf">sqlite_to_datetime</span><span class="p">(</span><span class="n">v</span><span class="p">:</span> <span class="nb">float</span><span class="p">)</span> <span class="o">-></span> <span class="n">datetime</span><span class="o">.</span><span class="n">datetime</span><span class="p">:</span>
<span class="c1"># Keep the UTC values coming back from the database</span>
<span class="c1"># as UTC</span>
<span class="k">return</span> <span class="n">datetime</span><span class="o">.</span><span class="n">datetime</span><span class="o">.</span><span class="n">fromtimestamp</span><span class="p">(</span><span class="n">v</span><span class="p">,</span> <span class="n">datetime</span><span class="o">.</span><span class="n">timezone</span><span class="o">.</span><span class="n">utc</span><span class="p">)</span>
<span class="n">registrar</span><span class="o">.</span><span class="n">register_converter</span><span class="p">(</span><span class="s2">"COMPLEX"</span><span class="p">,</span> <span class="n">sqlite_to_complex</span><span class="p">)</span>
<span class="n">registrar</span><span class="o">.</span><span class="n">register_converter</span><span class="p">(</span><span class="s2">"TIMESTAMP"</span><span class="p">,</span> <span class="n">sqlite_to_datetime</span><span class="p">)</span>
<span class="c1"># note that the type names are case sensitive and must match the</span>
<span class="c1"># registration</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"create table conversion(p POINT, c COMPLEX, t TIMESTAMP)"</span><span class="p">)</span>
<span class="c1"># convert going into database</span>
<span class="n">test_data</span> <span class="o">=</span> <span class="p">(</span><span class="n">Point</span><span class="p">(</span><span class="mf">5.2</span><span class="p">,</span> <span class="mf">7.6</span><span class="p">),</span> <span class="mi">3</span> <span class="o">+</span> <span class="mi">4</span><span class="n">j</span><span class="p">,</span> <span class="n">datetime</span><span class="o">.</span><span class="n">datetime</span><span class="o">.</span><span class="n">now</span><span class="p">())</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into conversion values(?, ?, ?)"</span><span class="p">,</span> <span class="n">test_data</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"inserted"</span><span class="p">,</span> <span class="n">test_data</span><span class="p">)</span>
<span class="c1"># and coming back out</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"querying data"</span><span class="p">)</span>
<span class="k">for</span> <span class="n">row</span> <span class="ow">in</span> <span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"select * from conversion"</span><span class="p">):</span>
<span class="k">for</span> <span class="n">i</span><span class="p">,</span> <span class="n">value</span> <span class="ow">in</span> <span class="nb">enumerate</span><span class="p">(</span><span class="n">row</span><span class="p">):</span>
<span class="nb">print</span><span class="p">(</span><span class="sa">f</span><span class="s2">"column </span><span class="si">{</span><span class="n">i</span><span class="si">}</span><span class="s2"> = </span><span class="si">{</span><span class="w"> </span><span class="n">value</span><span class="w"> </span><span class="si">!r}</span><span class="s2">"</span><span class="p">)</span>
<span class="c1"># clear registrar</span>
<span class="n">connection</span><span class="o">.</span><span class="n">cursor_factory</span> <span class="o">=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">Cursor</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">inserted (Point(5.2, 7.6), (3+4j), datetime.datetime(2024, 6, 16, 12, 43, 0, 373621))</span>
<span class="go">querying data</span>
<span class="go">column 0 = Point(5.2, 7.6)</span>
<span class="go">column 1 = (3+4j)</span>
<span class="go">column 2 = datetime.datetime(2024, 6, 16, 19, 43, 0, 373621, tzinfo=datetime.timezone.utc)</span>
</pre></div>
</div>
</section>
<section id="query-details">
<span id="example-query-details"></span><span id="index-19"></span><h2>Query details<a class="headerlink" href="#query-details" title="Link to this heading"></a></h2>
<p><a class="reference internal" href="ext.html#apsw.ext.query_info" title="apsw.ext.query_info"><code class="xref py py-meth docutils literal notranslate"><span class="pre">apsw.ext.query_info()</span></code></a> can provide a lot of information about a
query (without running it)</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="kn">import</span> <span class="nn">apsw.ext</span>
<span class="c1"># test tables</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"""</span>
<span class="s2"> create table customers(</span>
<span class="s2"> id INTEGER PRIMARY KEY,</span>
<span class="s2"> name CHAR,</span>
<span class="s2"> address CHAR);</span>
<span class="s2"> create table orders(</span>
<span class="s2"> id INTEGER PRIMARY KEY,</span>
<span class="s2"> customer_id INTEGER,</span>
<span class="s2"> item MY_OWN_TYPE);</span>
<span class="s2"> create index cust_addr on customers(address);</span>
<span class="s2">"""</span><span class="p">)</span>
<span class="n">query</span> <span class="o">=</span> <span class="s2">"""</span>
<span class="s2"> SELECT * FROM orders</span>
<span class="s2"> JOIN customers ON orders.customer_id=customers.id</span>
<span class="s2"> WHERE address = ?;</span>
<span class="s2"> SELECT 7;"""</span>
<span class="c1"># ask for all information available</span>
<span class="n">qd</span> <span class="o">=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">query_info</span><span class="p">(</span>
<span class="n">connection</span><span class="p">,</span>
<span class="n">query</span><span class="p">,</span>
<span class="n">actions</span><span class="o">=</span><span class="kc">True</span><span class="p">,</span> <span class="c1"># which tables/views etc and how they are accessed</span>
<span class="n">explain</span><span class="o">=</span><span class="kc">True</span><span class="p">,</span> <span class="c1"># shows low level VDBE</span>
<span class="n">explain_query_plan</span><span class="o">=</span><span class="kc">True</span><span class="p">,</span> <span class="c1"># how SQLite solves the query</span>
<span class="p">)</span>
<span class="c1"># help with formatting</span>
<span class="kn">import</span> <span class="nn">pprint</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"query"</span><span class="p">,</span> <span class="n">qd</span><span class="o">.</span><span class="n">query</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"</span><span class="se">\n</span><span class="s2">bindings_count"</span><span class="p">,</span> <span class="n">qd</span><span class="o">.</span><span class="n">bindings_count</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"</span><span class="se">\n</span><span class="s2">bindings_names"</span><span class="p">,</span> <span class="n">qd</span><span class="o">.</span><span class="n">bindings_names</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"</span><span class="se">\n</span><span class="s2">expanded_sql"</span><span class="p">,</span> <span class="n">qd</span><span class="o">.</span><span class="n">expanded_sql</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"</span><span class="se">\n</span><span class="s2">first_query"</span><span class="p">,</span> <span class="n">qd</span><span class="o">.</span><span class="n">first_query</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"</span><span class="se">\n</span><span class="s2">query_remaining"</span><span class="p">,</span> <span class="n">qd</span><span class="o">.</span><span class="n">query_remaining</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"</span><span class="se">\n</span><span class="s2">is_explain"</span><span class="p">,</span> <span class="n">qd</span><span class="o">.</span><span class="n">is_explain</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"</span><span class="se">\n</span><span class="s2">is_readonly"</span><span class="p">,</span> <span class="n">qd</span><span class="o">.</span><span class="n">is_readonly</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"</span><span class="se">\n</span><span class="s2">description</span><span class="se">\n</span><span class="s2">"</span><span class="p">,</span> <span class="n">pprint</span><span class="o">.</span><span class="n">pformat</span><span class="p">(</span><span class="n">qd</span><span class="o">.</span><span class="n">description</span><span class="p">))</span>
<span class="k">if</span> <span class="nb">hasattr</span><span class="p">(</span><span class="n">qd</span><span class="p">,</span> <span class="s2">"description_full"</span><span class="p">):</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"</span><span class="se">\n</span><span class="s2">description_full</span><span class="se">\n</span><span class="s2">"</span><span class="p">,</span> <span class="n">pprint</span><span class="o">.</span><span class="n">pformat</span><span class="p">(</span><span class="n">qd</span><span class="o">.</span><span class="n">description_full</span><span class="p">))</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"</span><span class="se">\n</span><span class="s2">query_plan</span><span class="se">\n</span><span class="s2">"</span><span class="p">,</span> <span class="n">pprint</span><span class="o">.</span><span class="n">pformat</span><span class="p">(</span><span class="n">qd</span><span class="o">.</span><span class="n">query_plan</span><span class="p">))</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"</span><span class="se">\n</span><span class="s2">First 5 actions</span><span class="se">\n</span><span class="s2">"</span><span class="p">,</span> <span class="n">pprint</span><span class="o">.</span><span class="n">pformat</span><span class="p">(</span><span class="n">qd</span><span class="o">.</span><span class="n">actions</span><span class="p">[:</span><span class="mi">5</span><span class="p">]))</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"</span><span class="se">\n</span><span class="s2">First 5 explain</span><span class="se">\n</span><span class="s2">"</span><span class="p">,</span> <span class="n">pprint</span><span class="o">.</span><span class="n">pformat</span><span class="p">(</span><span class="n">qd</span><span class="o">.</span><span class="n">explain</span><span class="p">[:</span><span class="mi">5</span><span class="p">]))</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">query</span>
<span class="go"> SELECT * FROM orders</span>
<span class="go"> JOIN customers ON orders.customer_id=customers.id</span>
<span class="go"> WHERE address = ?;</span>
<span class="go"> SELECT 7;</span>
<span class="go">bindings_count 1</span>
<span class="go">bindings_names (None,)</span>
<span class="go">expanded_sql None</span>
<span class="go">first_query</span>
<span class="go"> SELECT * FROM orders</span>
<span class="go"> JOIN customers ON orders.customer_id=customers.id</span>
<span class="go"> WHERE address = ?;</span>
<span class="go">query_remaining SELECT 7;</span>
<span class="go">is_explain 0</span>
<span class="go">is_readonly True</span>
<span class="go">description</span>
<span class="go"> (('id', 'INTEGER'),</span>
<span class="go"> ('customer_id', 'INTEGER'),</span>
<span class="go"> ('item', 'MY_OWN_TYPE'),</span>
<span class="go"> ('id', 'INTEGER'),</span>
<span class="go"> ('name', 'CHAR'),</span>
<span class="go"> ('address', 'CHAR'))</span>
<span class="go">description_full</span>
<span class="go"> (('id', 'INTEGER', 'main', 'orders', 'id'),</span>
<span class="go"> ('customer_id', 'INTEGER', 'main', 'orders', 'customer_id'),</span>
<span class="go"> ('item', 'MY_OWN_TYPE', 'main', 'orders', 'item'),</span>
<span class="go"> ('id', 'INTEGER', 'main', 'customers', 'id'),</span>
<span class="go"> ('name', 'CHAR', 'main', 'customers', 'name'),</span>
<span class="go"> ('address', 'CHAR', 'main', 'customers', 'address'))</span>
<span class="go">query_plan</span>
<span class="go"> QueryPlan(detail='QUERY PLAN',</span>
<span class="go"> sub=[QueryPlan(detail='SCAN orders', sub=None),</span>
<span class="go"> QueryPlan(detail='SEARCH customers USING INTEGER PRIMARY KEY '</span>
<span class="go"> '(rowid=?)',</span>
<span class="go"> sub=None)])</span>
<span class="go">First 5 actions</span>
<span class="go"> [QueryAction(action=21,</span>
<span class="go"> action_name='SQLITE_SELECT',</span>
<span class="go"> column_name=None,</span>
<span class="go"> database_name=None,</span>
<span class="go"> file_name=None,</span>
<span class="go"> function_name=None,</span>
<span class="go"> module_name=None,</span>
<span class="go"> operation=None,</span>
<span class="go"> pragma_name=None,</span>
<span class="go"> pragma_value=None,</span>
<span class="go"> table_name=None,</span>
<span class="go"> trigger_name=None,</span>
<span class="go"> trigger_or_view=None,</span>
<span class="go"> view_name=None),</span>
<span class="go"> QueryAction(action=20,</span>
<span class="go"> action_name='SQLITE_READ',</span>
<span class="go"> column_name='id',</span>
<span class="go"> database_name='main',</span>
<span class="go"> file_name=None,</span>
<span class="go"> function_name=None,</span>
<span class="go"> module_name=None,</span>
<span class="go"> operation=None,</span>
<span class="go"> pragma_name=None,</span>
<span class="go"> pragma_value=None,</span>
<span class="go"> table_name='orders',</span>
<span class="go"> trigger_name=None,</span>
<span class="go"> trigger_or_view=None,</span>
<span class="go"> view_name=None),</span>
<span class="go"> QueryAction(action=20,</span>
<span class="go"> action_name='SQLITE_READ',</span>
<span class="go"> column_name='customer_id',</span>
<span class="go"> database_name='main',</span>
<span class="go"> file_name=None,</span>
<span class="go"> function_name=None,</span>
<span class="go"> module_name=None,</span>
<span class="go"> operation=None,</span>
<span class="go"> pragma_name=None,</span>
<span class="go"> pragma_value=None,</span>
<span class="go"> table_name='orders',</span>
<span class="go"> trigger_name=None,</span>
<span class="go"> trigger_or_view=None,</span>
<span class="go"> view_name=None),</span>
<span class="go"> QueryAction(action=20,</span>
<span class="go"> action_name='SQLITE_READ',</span>
<span class="go"> column_name='item',</span>
<span class="go"> database_name='main',</span>
<span class="go"> file_name=None,</span>
<span class="go"> function_name=None,</span>
<span class="go"> module_name=None,</span>
<span class="go"> operation=None,</span>
<span class="go"> pragma_name=None,</span>
<span class="go"> pragma_value=None,</span>
<span class="go"> table_name='orders',</span>
<span class="go"> trigger_name=None,</span>
<span class="go"> trigger_or_view=None,</span>
<span class="go"> view_name=None),</span>
<span class="go"> QueryAction(action=20,</span>
<span class="go"> action_name='SQLITE_READ',</span>
<span class="go"> column_name='id',</span>
<span class="go"> database_name='main',</span>
<span class="go"> file_name=None,</span>
<span class="go"> function_name=None,</span>
<span class="go"> module_name=None,</span>
<span class="go"> operation=None,</span>
<span class="go"> pragma_name=None,</span>
<span class="go"> pragma_value=None,</span>
<span class="go"> table_name='customers',</span>
<span class="go"> trigger_name=None,</span>
<span class="go"> trigger_or_view=None,</span>
<span class="go"> view_name=None)]</span>
<span class="go">First 5 explain</span>
<span class="go"> [VDBEInstruction(addr=0,</span>
<span class="go"> opcode='Init',</span>
<span class="go"> comment=None,</span>
<span class="go"> p1=0,</span>
<span class="go"> p2=17,</span>
<span class="go"> p3=0,</span>
<span class="go"> p4=None,</span>
<span class="go"> p5=0),</span>
<span class="go"> VDBEInstruction(addr=1,</span>
<span class="go"> opcode='OpenRead',</span>
<span class="go"> comment=None,</span>
<span class="go"> p1=0,</span>
<span class="go"> p2=12,</span>
<span class="go"> p3=0,</span>
<span class="go"> p4='3',</span>
<span class="go"> p5=0),</span>
<span class="go"> VDBEInstruction(addr=2,</span>
<span class="go"> opcode='OpenRead',</span>
<span class="go"> comment=None,</span>
<span class="go"> p1=1,</span>
<span class="go"> p2=11,</span>
<span class="go"> p3=0,</span>
<span class="go"> p4='3',</span>
<span class="go"> p5=0),</span>
<span class="go"> VDBEInstruction(addr=3,</span>
<span class="go"> opcode='Rewind',</span>
<span class="go"> comment=None,</span>
<span class="go"> p1=0,</span>
<span class="go"> p2=16,</span>
<span class="go"> p3=0,</span>
<span class="go"> p4=None,</span>
<span class="go"> p5=0),</span>
<span class="go"> VDBEInstruction(addr=4,</span>
<span class="go"> opcode='Column',</span>
<span class="go"> comment=None,</span>
<span class="go"> p1=0,</span>
<span class="go"> p2=1,</span>
<span class="go"> p3=1,</span>
<span class="go"> p4=None,</span>
<span class="go"> p5=0)]</span>
</pre></div>
</div>
</section>
<section id="blob-i-o">
<span id="example-blob-io"></span><span id="index-20"></span><h2>Blob I/O<a class="headerlink" href="#blob-i-o" title="Link to this heading"></a></h2>
<p>BLOBS (binary large objects) are supported by SQLite. Note that you
cannot change the size of one, but you can allocate one filled with
zeroes, and then later open it and read / write the contents similar
to a file, without having the entire blob in memory. Use
<a class="reference internal" href="connection.html#apsw.Connection.blob_open" title="apsw.Connection.blob_open"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.blob_open()</span></code></a> to open a blob.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"create table blobby(x,y)"</span><span class="p">)</span>
<span class="c1"># Add a blob we will fill in later</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into blobby values(1, zeroblob(10000))"</span><span class="p">)</span>
<span class="c1"># Or as a binding</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into blobby values(2, ?)"</span><span class="p">,</span> <span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">zeroblob</span><span class="p">(</span><span class="mi">20000</span><span class="p">),))</span>
<span class="c1"># Open a blob for writing. We need to know the rowid</span>
<span class="n">rowid</span> <span class="o">=</span> <span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"select ROWID from blobby where x=1"</span><span class="p">)</span><span class="o">.</span><span class="n">get</span>
<span class="n">blob</span> <span class="o">=</span> <span class="n">connection</span><span class="o">.</span><span class="n">blob_open</span><span class="p">(</span><span class="s2">"main"</span><span class="p">,</span> <span class="s2">"blobby"</span><span class="p">,</span> <span class="s2">"y"</span><span class="p">,</span> <span class="n">rowid</span><span class="p">,</span> <span class="kc">True</span><span class="p">)</span>
<span class="n">blob</span><span class="o">.</span><span class="n">write</span><span class="p">(</span><span class="sa">b</span><span class="s2">"hello world"</span><span class="p">)</span>
<span class="n">blob</span><span class="o">.</span><span class="n">seek</span><span class="p">(</span><span class="mi">2000</span><span class="p">)</span>
<span class="n">blob</span><span class="o">.</span><span class="n">read</span><span class="p">(</span><span class="mi">24</span><span class="p">)</span>
<span class="c1"># seek relative to the end</span>
<span class="n">blob</span><span class="o">.</span><span class="n">seek</span><span class="p">(</span><span class="o">-</span><span class="mi">32</span><span class="p">,</span> <span class="mi">2</span><span class="p">)</span>
<span class="n">blob</span><span class="o">.</span><span class="n">write</span><span class="p">(</span><span class="sa">b</span><span class="s2">"hello world, again"</span><span class="p">)</span>
<span class="n">blob</span><span class="o">.</span><span class="n">close</span><span class="p">()</span>
</pre></div>
</div>
</section>
<section id="backup-an-open-database">
<span id="example-backup"></span><span id="index-21"></span><h2>Backup an open database<a class="headerlink" href="#backup-an-open-database" title="Link to this heading"></a></h2>
<p>You can <a class="reference internal" href="backup.html#backup"><span class="std std-ref">backup</span></a> a database that is open. The pages are copied in
batches of your choosing and allow continued use of the source
database.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># We will copy a disk database into this memory database</span>
<span class="n">destination</span> <span class="o">=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">Connection</span><span class="p">(</span><span class="s2">":memory:"</span><span class="p">)</span>
<span class="c1"># Copy into destination</span>
<span class="k">with</span> <span class="n">destination</span><span class="o">.</span><span class="n">backup</span><span class="p">(</span><span class="s2">"main"</span><span class="p">,</span> <span class="n">connection</span><span class="p">,</span> <span class="s2">"main"</span><span class="p">)</span> <span class="k">as</span> <span class="n">backup</span><span class="p">:</span>
<span class="c1"># The source database can change while doing the backup</span>
<span class="c1"># and the backup will still pick up those changes</span>
<span class="k">while</span> <span class="ow">not</span> <span class="n">backup</span><span class="o">.</span><span class="n">done</span><span class="p">:</span>
<span class="n">backup</span><span class="o">.</span><span class="n">step</span><span class="p">(</span><span class="mi">7</span><span class="p">)</span> <span class="c1"># copy up to 7 pages each time</span>
<span class="c1"># monitor progress</span>
<span class="nb">print</span><span class="p">(</span><span class="n">backup</span><span class="o">.</span><span class="n">remaining</span><span class="p">,</span> <span class="n">backup</span><span class="o">.</span><span class="n">page_count</span><span class="p">)</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">15 22</span>
<span class="go">8 22</span>
<span class="go">1 22</span>
<span class="go">0 22</span>
</pre></div>
</div>
</section>
<section id="authorizer-control-what-sql-can-do">
<span id="example-authorizer"></span><span id="index-22"></span><h2>Authorizer (control what SQL can do)<a class="headerlink" href="#authorizer-control-what-sql-can-do" title="Link to this heading"></a></h2>
<p>You can allow, deny, or ignore what SQL does. Use
<a class="reference internal" href="connection.html#apsw.Connection.authorizer" title="apsw.Connection.authorizer"><code class="xref py py-attr docutils literal notranslate"><span class="pre">Connection.authorizer</span></code></a> to set an authorizer.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="k">def</span> <span class="nf">auth</span><span class="p">(</span>
<span class="n">operation</span><span class="p">:</span> <span class="nb">int</span><span class="p">,</span> <span class="n">p1</span><span class="p">:</span> <span class="n">Optional</span><span class="p">[</span><span class="nb">str</span><span class="p">],</span> <span class="n">p2</span><span class="p">:</span> <span class="n">Optional</span><span class="p">[</span><span class="nb">str</span><span class="p">],</span> <span class="n">db_name</span><span class="p">:</span> <span class="n">Optional</span><span class="p">[</span><span class="nb">str</span><span class="p">],</span> <span class="n">trigger_or_view</span><span class="p">:</span> <span class="n">Optional</span><span class="p">[</span><span class="nb">str</span><span class="p">]</span>
<span class="p">)</span> <span class="o">-></span> <span class="nb">int</span><span class="p">:</span>
<span class="w"> </span><span class="sd">"""Called when each operation is prepared. We can return SQLITE_OK, SQLITE_DENY or</span>
<span class="sd"> SQLITE_IGNORE"""</span>
<span class="c1"># find the operation name</span>
<span class="nb">print</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">mapping_authorizer_function</span><span class="p">[</span><span class="n">operation</span><span class="p">],</span> <span class="n">p1</span><span class="p">,</span> <span class="n">p2</span><span class="p">,</span> <span class="n">db_name</span><span class="p">,</span> <span class="n">trigger_or_view</span><span class="p">)</span>
<span class="k">if</span> <span class="n">operation</span> <span class="o">==</span> <span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_CREATE_TABLE</span> <span class="ow">and</span> <span class="n">p1</span> <span class="ow">and</span> <span class="n">p1</span><span class="o">.</span><span class="n">startswith</span><span class="p">(</span><span class="s2">"private"</span><span class="p">):</span>
<span class="k">return</span> <span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_DENY</span> <span class="c1"># not allowed to create tables whose names start with private</span>
<span class="k">return</span> <span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_OK</span> <span class="c1"># always allow</span>
<span class="n">connection</span><span class="o">.</span><span class="n">authorizer</span> <span class="o">=</span> <span class="n">auth</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into names values('foo')"</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"select name from names limit 1"</span><span class="p">)</span>
<span class="k">try</span><span class="p">:</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"create table private_stuff(secret)"</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"Created secret table!"</span><span class="p">)</span>
<span class="k">except</span> <span class="ne">Exception</span> <span class="k">as</span> <span class="n">e</span><span class="p">:</span>
<span class="nb">print</span><span class="p">(</span><span class="n">e</span><span class="p">)</span>
<span class="c1"># Clear authorizer</span>
<span class="n">connection</span><span class="o">.</span><span class="n">authorizer</span> <span class="o">=</span> <span class="kc">None</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">SQLITE_INSERT names None main None</span>
<span class="go">SQLITE_SELECT None None None None</span>
<span class="go">SQLITE_READ names name main None</span>
<span class="go">SQLITE_INSERT sqlite_master None main None</span>
<span class="go">SQLITE_CREATE_TABLE private_stuff None main None</span>
<span class="go">AuthError: not authorized</span>
</pre></div>
</div>
</section>
<section id="progress-handler">
<span id="example-progress-handler"></span><span id="index-23"></span><h2>Progress handler<a class="headerlink" href="#progress-handler" title="Link to this heading"></a></h2>
<p>Some operations (eg joins, sorting) can take many operations to
complete. Register a progress handler callback with
<a class="reference internal" href="connection.html#apsw.Connection.set_progress_handler" title="apsw.Connection.set_progress_handler"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.set_progress_handler()</span></code></a> which lets you provide
feedback and allows cancelling.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># create a table with random numbers</span>
<span class="k">with</span> <span class="n">connection</span><span class="p">:</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"create table numbers(x)"</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">executemany</span><span class="p">(</span><span class="s2">"insert into numbers values(?)"</span><span class="p">,</span> <span class="p">((</span><span class="n">random</span><span class="o">.</span><span class="n">randint</span><span class="p">(</span><span class="mi">0</span><span class="p">,</span> <span class="mi">9999999999</span><span class="p">),)</span> <span class="k">for</span> <span class="n">_</span> <span class="ow">in</span> <span class="nb">range</span><span class="p">(</span><span class="mi">100</span><span class="p">)))</span>
<span class="k">def</span> <span class="nf">progress_handler</span><span class="p">()</span> <span class="o">-></span> <span class="nb">bool</span><span class="p">:</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"progress handler called"</span><span class="p">)</span>
<span class="k">return</span> <span class="kc">False</span> <span class="c1"># returning True aborts</span>
<span class="c1"># register handler every 50 vdbe instructions</span>
<span class="n">connection</span><span class="o">.</span><span class="n">set_progress_handler</span><span class="p">(</span><span class="n">progress_handler</span><span class="p">,</span> <span class="mi">50</span><span class="p">)</span>
<span class="c1"># Sorting the numbers to find the biggest</span>
<span class="k">for</span> <span class="n">max_num</span> <span class="ow">in</span> <span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"select max(x) from numbers"</span><span class="p">):</span>
<span class="nb">print</span><span class="p">(</span><span class="n">max_num</span><span class="p">)</span>
<span class="c1"># Clear handler</span>
<span class="n">connection</span><span class="o">.</span><span class="n">set_progress_handler</span><span class="p">(</span><span class="kc">None</span><span class="p">)</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">progress handler called</span>
<span class="go">progress handler called</span>
<span class="go">progress handler called</span>
<span class="go">progress handler called</span>
<span class="go">progress handler called</span>
<span class="go">progress handler called</span>
<span class="go">progress handler called</span>
<span class="go">progress handler called</span>
<span class="go">(9723915095,)</span>
</pre></div>
</div>
</section>
<section id="file-control">
<span id="example-filecontrol"></span><span id="index-24"></span><h2>File Control<a class="headerlink" href="#file-control" title="Link to this heading"></a></h2>
<p>We can get/set low level information using the
<a class="reference internal" href="connection.html#apsw.Connection.file_control" title="apsw.Connection.file_control"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.file_control()</span></code></a> interface. In this example we get
the <a class="reference external" href="https://sqlite.org/c3ref/c_fcntl_begin_atomic_write.html#sqlitefcntldataversion">data version</a>.
There is a <a class="reference external" href="https://sqlite.org/pragma.html#pragma_data_version">pragma</a> but it
doesn’t change for commits on the same connection.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># We use ctypes to provide the correct C level data types and pointers</span>
<span class="kn">import</span> <span class="nn">ctypes</span>
<span class="k">def</span> <span class="nf">get_data_version</span><span class="p">(</span><span class="n">db</span><span class="p">):</span>
<span class="c1"># unsigned 32 bit integer</span>
<span class="n">data_version</span> <span class="o">=</span> <span class="n">ctypes</span><span class="o">.</span><span class="n">c_uint32</span><span class="p">(</span><span class="mi">0</span><span class="p">)</span>
<span class="n">ok</span> <span class="o">=</span> <span class="n">db</span><span class="o">.</span><span class="n">file_control</span><span class="p">(</span>
<span class="s2">"main"</span><span class="p">,</span> <span class="c1"># or an attached database name</span>
<span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_FCNTL_DATA_VERSION</span><span class="p">,</span> <span class="c1"># code</span>
<span class="n">ctypes</span><span class="o">.</span><span class="n">addressof</span><span class="p">(</span><span class="n">data_version</span><span class="p">),</span>
<span class="p">)</span> <span class="c1"># pass C level pointer</span>
<span class="k">assert</span> <span class="n">ok</span><span class="p">,</span> <span class="s2">"SQLITE_FCNTL_DATA_VERSION was not understood!"</span>
<span class="k">return</span> <span class="n">data_version</span><span class="o">.</span><span class="n">value</span>
<span class="c1"># Show starting values</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"fcntl"</span><span class="p">,</span> <span class="n">get_data_version</span><span class="p">(</span><span class="n">connection</span><span class="p">),</span> <span class="s2">"pragma"</span><span class="p">,</span> <span class="n">connection</span><span class="o">.</span><span class="n">pragma</span><span class="p">(</span><span class="s2">"data_version"</span><span class="p">))</span>
<span class="c1"># See the fcntl value versus pragma value</span>
<span class="k">for</span> <span class="n">sql</span> <span class="ow">in</span> <span class="p">(</span>
<span class="s2">"create table fcntl_example(x)"</span><span class="p">,</span>
<span class="s2">"begin ; insert into fcntl_example values(3)"</span><span class="p">,</span>
<span class="c1"># we can see the version doesn't change inside a transaction</span>
<span class="s2">"insert into fcntl_example values(4)"</span><span class="p">,</span>
<span class="s2">"commit"</span><span class="p">,</span>
<span class="s2">"pragma user_version=1234"</span><span class="p">,</span>
<span class="p">):</span>
<span class="nb">print</span><span class="p">(</span><span class="n">sql</span><span class="p">)</span>
<span class="n">connection</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="nb">print</span><span class="p">(</span><span class="s2">"fcntl"</span><span class="p">,</span> <span class="n">get_data_version</span><span class="p">(</span><span class="n">connection</span><span class="p">),</span> <span class="s2">"pragma"</span><span class="p">,</span> <span class="n">connection</span><span class="o">.</span><span class="n">pragma</span><span class="p">(</span><span class="s2">"data_version"</span><span class="p">))</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">fcntl 40 pragma 2</span>
<span class="go">create table fcntl_example(x)</span>
<span class="go">fcntl 41 pragma 2</span>
<span class="go">begin ; insert into fcntl_example values(3)</span>
<span class="go">fcntl 41 pragma 2</span>
<span class="go">insert into fcntl_example values(4)</span>
<span class="go">fcntl 41 pragma 2</span>
<span class="go">commit</span>
<span class="go">fcntl 42 pragma 2</span>
<span class="go">pragma user_version=1234</span>
<span class="go">fcntl 43 pragma 2</span>
</pre></div>
</div>
</section>
<section id="commit-hook">
<span id="example-commit-hook"></span><span id="index-25"></span><h2>Commit hook<a class="headerlink" href="#commit-hook" title="Link to this heading"></a></h2>
<p>A commit hook can allow or veto commits. Register a commit hook
with <a class="reference internal" href="connection.html#apsw.Connection.set_commit_hook" title="apsw.Connection.set_commit_hook"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.set_commit_hook()</span></code></a>.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="k">def</span> <span class="nf">my_commit_hook</span><span class="p">()</span> <span class="o">-></span> <span class="nb">bool</span><span class="p">:</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"in commit hook"</span><span class="p">)</span>
<span class="n">hour</span> <span class="o">=</span> <span class="n">time</span><span class="o">.</span><span class="n">localtime</span><span class="p">()[</span><span class="mi">3</span><span class="p">]</span>
<span class="k">if</span> <span class="n">hour</span> <span class="o">>=</span> <span class="mi">8</span> <span class="ow">and</span> <span class="n">hour</span> <span class="o"><</span> <span class="mi">18</span><span class="p">:</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"commits okay at this time"</span><span class="p">)</span>
<span class="k">return</span> <span class="kc">False</span> <span class="c1"># let commit go ahead</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"no commits out of hours"</span><span class="p">)</span>
<span class="k">return</span> <span class="kc">True</span> <span class="c1"># abort commits outside of 8am through 6pm</span>
<span class="n">connection</span><span class="o">.</span><span class="n">set_commit_hook</span><span class="p">(</span><span class="n">my_commit_hook</span><span class="p">)</span>
<span class="k">try</span><span class="p">:</span>
<span class="k">with</span> <span class="n">connection</span><span class="p">:</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"""create table example(x,y,z);</span>
<span class="s2"> insert into example values (3,4,5)"""</span><span class="p">)</span>
<span class="k">except</span> <span class="n">apsw</span><span class="o">.</span><span class="n">ConstraintError</span><span class="p">:</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"commit was not allowed"</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">set_commit_hook</span><span class="p">(</span><span class="kc">None</span><span class="p">)</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">in commit hook</span>
<span class="go">commits okay at this time</span>
</pre></div>
</div>
</section>
<section id="update-hook">
<span id="example-update-hook"></span><span id="index-26"></span><h2>Update hook<a class="headerlink" href="#update-hook" title="Link to this heading"></a></h2>
<p>Update hooks let you know that data has been added, changed, or
removed. For example you could use this to discard cached
information. Register a hook using
<a class="reference internal" href="connection.html#apsw.Connection.set_update_hook" title="apsw.Connection.set_update_hook"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.set_update_hook()</span></code></a>.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="k">def</span> <span class="nf">my_update_hook</span><span class="p">(</span><span class="nb">type</span><span class="p">:</span> <span class="nb">int</span><span class="p">,</span> <span class="n">db_name</span><span class="p">:</span> <span class="nb">str</span><span class="p">,</span> <span class="n">table_name</span><span class="p">:</span> <span class="nb">str</span><span class="p">,</span> <span class="n">rowid</span><span class="p">:</span> <span class="nb">int</span><span class="p">)</span> <span class="o">-></span> <span class="kc">None</span><span class="p">:</span>
<span class="n">op</span><span class="p">:</span> <span class="nb">str</span> <span class="o">=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">mapping_authorizer_function</span><span class="p">[</span><span class="nb">type</span><span class="p">]</span>
<span class="nb">print</span><span class="p">(</span><span class="sa">f</span><span class="s2">"Updated: </span><span class="si">{</span><span class="w"> </span><span class="n">op</span><span class="w"> </span><span class="si">}</span><span class="s2"> db </span><span class="si">{</span><span class="w"> </span><span class="n">db_name</span><span class="w"> </span><span class="si">}</span><span class="s2">, table </span><span class="si">{</span><span class="w"> </span><span class="n">table_name</span><span class="w"> </span><span class="si">}</span><span class="s2">, rowid </span><span class="si">{</span><span class="w"> </span><span class="n">rowid</span><span class="w"> </span><span class="si">}</span><span class="s2">"</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">set_update_hook</span><span class="p">(</span><span class="n">my_update_hook</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into names values(?)"</span><span class="p">,</span> <span class="p">(</span><span class="s2">"file93"</span><span class="p">,))</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"update names set name=? where name=?"</span><span class="p">,</span> <span class="p">(</span><span class="s2">"file94"</span><span class="p">,</span> <span class="s2">"file93"</span><span class="p">))</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"delete from names where name=?"</span><span class="p">,</span> <span class="p">(</span><span class="s2">"file94"</span><span class="p">,))</span>
<span class="c1"># Clear the hook</span>
<span class="n">connection</span><span class="o">.</span><span class="n">set_update_hook</span><span class="p">(</span><span class="kc">None</span><span class="p">)</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">Updated: SQLITE_INSERT db main, table names, rowid 7</span>
<span class="go">Updated: SQLITE_UPDATE db main, table names, rowid 7</span>
<span class="go">Updated: SQLITE_DELETE db main, table names, rowid 7</span>
</pre></div>
</div>
</section>
<section id="virtual-tables">
<span id="example-virtual-tables"></span><span id="index-27"></span><h2>Virtual tables<a class="headerlink" href="#virtual-tables" title="Link to this heading"></a></h2>
<p><a class="reference internal" href="vtable.html#virtualtables"><span class="std std-ref">Virtual tables</span></a> let you provide data on demand
as a SQLite table so you can use SQL queries against that data.
Writing your own virtual table requires understanding how to return
less than all the data via the <a class="reference external" href="https://www.sqlite.org/vtab.html#the_xbestindex_method">BestIndex</a> method.</p>
<p>You can export a Python function as a virtual table in 3 lines of
code using <a class="reference internal" href="ext.html#apsw.ext.make_virtual_module" title="apsw.ext.make_virtual_module"><code class="xref py py-func docutils literal notranslate"><span class="pre">apsw.ext.make_virtual_module()</span></code></a>, being able to
provide both positional and keyword arguments.</p>
<p>For the first example you’ll find <a class="reference internal" href="ext.html#apsw.ext.generate_series" title="apsw.ext.generate_series"><code class="xref py py-meth docutils literal notranslate"><span class="pre">apsw.ext.generate_series()</span></code></a>
useful instead.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># Yield a row at a time</span>
<span class="k">def</span> <span class="nf">table_range</span><span class="p">(</span><span class="n">start</span><span class="o">=</span><span class="mi">1</span><span class="p">,</span> <span class="n">stop</span><span class="o">=</span><span class="mi">100</span><span class="p">,</span> <span class="n">step</span><span class="o">=</span><span class="mi">1</span><span class="p">):</span>
<span class="k">for</span> <span class="n">i</span> <span class="ow">in</span> <span class="nb">range</span><span class="p">(</span><span class="n">start</span><span class="p">,</span> <span class="n">stop</span> <span class="o">+</span> <span class="mi">1</span><span class="p">,</span> <span class="n">step</span><span class="p">):</span>
<span class="k">yield</span> <span class="p">(</span><span class="n">i</span><span class="p">,)</span>
<span class="c1"># set column names</span>
<span class="n">table_range</span><span class="o">.</span><span class="n">columns</span> <span class="o">=</span> <span class="p">(</span><span class="s2">"value"</span><span class="p">,)</span>
<span class="c1"># set how to access what table_range returns</span>
<span class="n">table_range</span><span class="o">.</span><span class="n">column_access</span> <span class="o">=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">VTColumnAccess</span><span class="o">.</span><span class="n">By_Index</span>
<span class="c1"># register it</span>
<span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">make_virtual_module</span><span class="p">(</span><span class="n">connection</span><span class="p">,</span> <span class="s2">"range"</span><span class="p">,</span> <span class="n">table_range</span><span class="p">)</span>
<span class="c1"># see it work. we can provide both positional and keyword</span>
<span class="c1"># arguments</span>
<span class="n">query</span> <span class="o">=</span> <span class="s2">"SELECT * FROM range(90) WHERE step=2"</span>
<span class="nb">print</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">format_query_table</span><span class="p">(</span><span class="n">connection</span><span class="p">,</span> <span class="n">query</span><span class="p">))</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">┌───────┐</span>
<span class="go">│ value │</span>
<span class="go">│ 90 │</span>
<span class="go">│ 92 │</span>
<span class="go">│ 94 │</span>
<span class="go">│ 96 │</span>
<span class="go">│ 98 │</span>
<span class="go">│ 100 │</span>
<span class="go">└───────┘</span>
</pre></div>
</div>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># the parameters are hidden columns so '*' doesn't select them</span>
<span class="c1"># but you can ask</span>
<span class="n">query</span> <span class="o">=</span> <span class="s2">"SELECT *, start, stop, step FROM range(89) WHERE step=3"</span>
<span class="nb">print</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">format_query_table</span><span class="p">(</span><span class="n">connection</span><span class="p">,</span> <span class="n">query</span><span class="p">))</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">┌───────┬───────┬──────┬──────┐</span>
<span class="go">│ value │ start │ stop │ step │</span>
<span class="go">│ 89 │ 89 │ 100 │ 3 │</span>
<span class="go">│ 92 │ 89 │ 100 │ 3 │</span>
<span class="go">│ 95 │ 89 │ 100 │ 3 │</span>
<span class="go">│ 98 │ 89 │ 100 │ 3 │</span>
<span class="go">└───────┴───────┴──────┴──────┘</span>
</pre></div>
</div>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># Expose the unicode database.</span>
<span class="kn">import</span> <span class="nn">unicodedata</span>
<span class="c1"># A more complex example exporting unicodedata module</span>
<span class="c1"># The methods we will call on each codepoint</span>
<span class="n">unicode_methods</span> <span class="o">=</span> <span class="p">(</span>
<span class="s2">"name"</span><span class="p">,</span>
<span class="s2">"decimal"</span><span class="p">,</span>
<span class="s2">"digit"</span><span class="p">,</span>
<span class="s2">"numeric"</span><span class="p">,</span>
<span class="s2">"category"</span><span class="p">,</span>
<span class="s2">"combining"</span><span class="p">,</span>
<span class="s2">"bidirectional"</span><span class="p">,</span>
<span class="s2">"east_asian_width"</span><span class="p">,</span>
<span class="s2">"mirrored"</span><span class="p">,</span>
<span class="s2">"decomposition"</span><span class="p">,</span>
<span class="p">)</span>
<span class="c1"># the function we will turn into a virtual table returning</span>
<span class="c1"># each row as a dict</span>
<span class="k">def</span> <span class="nf">unicode_data</span><span class="p">(</span><span class="n">start</span><span class="o">=</span><span class="mi">0</span><span class="p">,</span> <span class="n">stop</span><span class="o">=</span><span class="n">sys</span><span class="o">.</span><span class="n">maxunicode</span><span class="p">):</span>
<span class="c1"># some methods raise ValueError on some codepoints</span>
<span class="k">def</span> <span class="nf">call</span><span class="p">(</span><span class="n">meth</span><span class="p">:</span> <span class="nb">str</span><span class="p">,</span> <span class="n">c</span><span class="p">:</span> <span class="nb">str</span><span class="p">):</span>
<span class="k">try</span><span class="p">:</span>
<span class="k">return</span> <span class="nb">getattr</span><span class="p">(</span><span class="n">unicodedata</span><span class="p">,</span> <span class="n">meth</span><span class="p">)(</span><span class="n">c</span><span class="p">)</span>
<span class="k">except</span> <span class="ne">ValueError</span><span class="p">:</span>
<span class="k">return</span> <span class="kc">None</span>
<span class="k">for</span> <span class="n">c</span> <span class="ow">in</span> <span class="nb">range</span><span class="p">(</span><span class="n">start</span><span class="p">,</span> <span class="n">stop</span> <span class="o">+</span> <span class="mi">1</span><span class="p">):</span>
<span class="k">yield</span> <span class="p">{</span><span class="n">k</span><span class="p">:</span> <span class="n">call</span><span class="p">(</span><span class="n">k</span><span class="p">,</span> <span class="nb">chr</span><span class="p">(</span><span class="n">c</span><span class="p">))</span> <span class="k">for</span> <span class="n">k</span> <span class="ow">in</span> <span class="n">unicode_methods</span><span class="p">}</span>
<span class="c1"># setup column names and access</span>
<span class="n">unicode_data</span><span class="o">.</span><span class="n">columns</span> <span class="o">=</span> <span class="n">unicode_methods</span>
<span class="n">unicode_data</span><span class="o">.</span><span class="n">column_access</span> <span class="o">=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">VTColumnAccess</span><span class="o">.</span><span class="n">By_Name</span>
<span class="c1"># register</span>
<span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">make_virtual_module</span><span class="p">(</span><span class="n">connection</span><span class="p">,</span> <span class="s2">"unicode_data"</span><span class="p">,</span> <span class="n">unicode_data</span><span class="p">)</span>
<span class="c1"># how many codepoints are in each category?</span>
<span class="n">query</span> <span class="o">=</span> <span class="s2">"""</span>
<span class="s2"> SELECT count(*), category FROM unicode_data</span>
<span class="s2"> WHERE stop = 0xffff -- BMP only</span>
<span class="s2"> GROUP BY category</span>
<span class="s2"> ORDER BY category</span>
<span class="s2"> LIMIT 10"""</span>
<span class="nb">print</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">format_query_table</span><span class="p">(</span><span class="n">connection</span><span class="p">,</span> <span class="n">query</span><span class="p">))</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">┌──────────┬──────────┐</span>
<span class="go">│ count(*) │ category │</span>
<span class="go">│ 65 │ Cc │</span>
<span class="go">│ 43 │ Cf │</span>
<span class="go">│ 1454 │ Cn │</span>
<span class="go">│ 6400 │ Co │</span>
<span class="go">│ 2048 │ Cs │</span>
<span class="go">│ 1445 │ Ll │</span>
<span class="go">│ 236 │ Lm │</span>
<span class="go">│ 46126 │ Lo │</span>
<span class="go">│ 31 │ Lt │</span>
<span class="go">│ 1127 │ Lu │</span>
<span class="go">└──────────┴──────────┘</span>
</pre></div>
</div>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># A more complex example - given a list of directories return information</span>
<span class="c1"># about the files within them recursively</span>
<span class="k">def</span> <span class="nf">get_files_info</span><span class="p">(</span>
<span class="n">directories</span><span class="p">:</span> <span class="nb">str</span><span class="p">,</span> <span class="n">sep</span><span class="p">:</span> <span class="nb">str</span> <span class="o">=</span> <span class="n">os</span><span class="o">.</span><span class="n">pathsep</span><span class="p">,</span> <span class="o">*</span><span class="p">,</span> <span class="n">ignore_symlinks</span><span class="p">:</span> <span class="nb">bool</span> <span class="o">=</span> <span class="kc">True</span>
<span class="p">)</span> <span class="o">-></span> <span class="n">Iterator</span><span class="p">[</span><span class="nb">dict</span><span class="p">[</span><span class="nb">str</span><span class="p">,</span> <span class="n">Any</span><span class="p">]]:</span>
<span class="k">for</span> <span class="n">root</span> <span class="ow">in</span> <span class="n">directories</span><span class="o">.</span><span class="n">split</span><span class="p">(</span><span class="n">sep</span><span class="p">):</span>
<span class="k">with</span> <span class="n">os</span><span class="o">.</span><span class="n">scandir</span><span class="p">(</span><span class="n">root</span><span class="p">)</span> <span class="k">as</span> <span class="n">sd</span><span class="p">:</span>
<span class="k">for</span> <span class="n">entry</span> <span class="ow">in</span> <span class="n">sd</span><span class="p">:</span>
<span class="k">if</span> <span class="n">entry</span><span class="o">.</span><span class="n">is_symlink</span><span class="p">()</span> <span class="ow">and</span> <span class="n">ignore_symlinks</span><span class="p">:</span>
<span class="k">continue</span>
<span class="k">if</span> <span class="n">entry</span><span class="o">.</span><span class="n">is_dir</span><span class="p">():</span>
<span class="k">yield from</span> <span class="n">get_files_info</span><span class="p">(</span><span class="n">os</span><span class="o">.</span><span class="n">path</span><span class="o">.</span><span class="n">join</span><span class="p">(</span><span class="n">root</span><span class="p">,</span> <span class="n">entry</span><span class="o">.</span><span class="n">name</span><span class="p">),</span> <span class="n">ignore_symlinks</span><span class="o">=</span><span class="n">ignore_symlinks</span><span class="p">)</span>
<span class="k">elif</span> <span class="n">entry</span><span class="o">.</span><span class="n">is_file</span><span class="p">():</span>
<span class="n">s</span> <span class="o">=</span> <span class="n">entry</span><span class="o">.</span><span class="n">stat</span><span class="p">()</span>
<span class="k">yield</span> <span class="p">{</span>
<span class="s2">"directory"</span><span class="p">:</span> <span class="n">root</span><span class="p">,</span>
<span class="s2">"name"</span><span class="p">:</span> <span class="n">entry</span><span class="o">.</span><span class="n">name</span><span class="p">,</span>
<span class="s2">"extension"</span><span class="p">:</span> <span class="n">os</span><span class="o">.</span><span class="n">path</span><span class="o">.</span><span class="n">splitext</span><span class="p">(</span><span class="n">entry</span><span class="o">.</span><span class="n">name</span><span class="p">)[</span><span class="mi">1</span><span class="p">],</span>
<span class="o">**</span><span class="p">{</span><span class="n">k</span><span class="p">:</span> <span class="nb">getattr</span><span class="p">(</span><span class="n">s</span><span class="p">,</span> <span class="n">k</span><span class="p">)</span> <span class="k">for</span> <span class="n">k</span> <span class="ow">in</span> <span class="n">get_files_info</span><span class="o">.</span><span class="n">stat_columns</span><span class="p">},</span>
<span class="p">}</span>
<span class="c1"># which stat columns do we want?</span>
<span class="n">get_files_info</span><span class="o">.</span><span class="n">stat_columns</span> <span class="o">=</span> <span class="nb">tuple</span><span class="p">(</span><span class="n">n</span> <span class="k">for</span> <span class="n">n</span> <span class="ow">in</span> <span class="nb">dir</span><span class="p">(</span><span class="n">os</span><span class="o">.</span><span class="n">stat</span><span class="p">(</span><span class="s2">"."</span><span class="p">))</span> <span class="k">if</span> <span class="n">n</span><span class="o">.</span><span class="n">startswith</span><span class="p">(</span><span class="s2">"st_"</span><span class="p">))</span>
<span class="c1"># setup columns and access by providing an example of the first entry returned</span>
<span class="n">get_files_info</span><span class="o">.</span><span class="n">columns</span><span class="p">,</span> <span class="n">get_files_info</span><span class="o">.</span><span class="n">column_access</span> <span class="o">=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">get_column_names</span><span class="p">(</span><span class="nb">next</span><span class="p">(</span><span class="n">get_files_info</span><span class="p">(</span><span class="s2">"."</span><span class="p">)))</span>
<span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">make_virtual_module</span><span class="p">(</span><span class="n">connection</span><span class="p">,</span> <span class="s2">"files_info"</span><span class="p">,</span> <span class="n">get_files_info</span><span class="p">)</span>
<span class="c1"># all the sys.path directories</span>
<span class="n">bindings</span> <span class="o">=</span> <span class="p">(</span>
<span class="n">os</span><span class="o">.</span><span class="n">pathsep</span><span class="o">.</span><span class="n">join</span><span class="p">(</span>
<span class="n">p</span>
<span class="k">for</span> <span class="n">p</span> <span class="ow">in</span> <span class="n">sys</span><span class="o">.</span><span class="n">path</span>
<span class="k">if</span> <span class="n">os</span><span class="o">.</span><span class="n">path</span><span class="o">.</span><span class="n">isdir</span><span class="p">(</span><span class="n">p</span><span class="p">)</span>
<span class="c1"># except our current one</span>
<span class="ow">and</span> <span class="ow">not</span> <span class="n">os</span><span class="o">.</span><span class="n">path</span><span class="o">.</span><span class="n">samefile</span><span class="p">(</span><span class="n">p</span><span class="p">,</span> <span class="s2">"."</span><span class="p">)</span>
<span class="p">),</span>
<span class="p">)</span>
<span class="c1"># Find the 3 biggest files that aren't libraries</span>
<span class="n">query</span> <span class="o">=</span> <span class="s2">"""SELECT st_size, directory, name</span>
<span class="s2"> FROM files_info(?)</span>
<span class="s2"> WHERE extension NOT IN ('.a', '.so')</span>
<span class="s2"> ORDER BY st_size DESC</span>
<span class="s2"> LIMIT 3"""</span>
<span class="nb">print</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">format_query_table</span><span class="p">(</span><span class="n">connection</span><span class="p">,</span> <span class="n">query</span><span class="p">,</span> <span class="n">bindings</span><span class="p">))</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">┌─────────┬──────────────────────────────────────────┬─────────────────────────┐</span>
<span class="go">│ st_size │ directory │ name │</span>
<span class="go">├─────────┼──────────────────────────────────────────┼─────────────────────────┤</span>
<span class="go">│ 805508 │ /usr/lib/python3.12/pydoc_data │ topics.py │</span>
<span class="go">├─────────┼──────────────────────────────────────────┼─────────────────────────┤</span>
<span class="go">│ 502306 │ /usr/lib/python3.12/pydoc_data/__pycache │ topics.cpython-312.pyc │</span>
<span class="go">│ │ __ │ │</span>
<span class="go">├─────────┼──────────────────────────────────────────┼─────────────────────────┤</span>
<span class="go">│ 245231 │ /usr/lib/python3.12/tkinter/__pycache__ │ __init__.cpython- │</span>
<span class="go">│ │ │ 312.pyc │</span>
<span class="go">└─────────┴──────────────────────────────────────────┴─────────────────────────┘</span>
</pre></div>
</div>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># Find the 3 oldest Python files</span>
<span class="n">query</span> <span class="o">=</span> <span class="s2">"""SELECT DATE(st_ctime, 'auto') AS date, directory, name</span>
<span class="s2"> FROM files_info(?)</span>
<span class="s2"> WHERE extension='.py'</span>
<span class="s2"> ORDER BY st_size DESC</span>
<span class="s2"> LIMIT 3"""</span>
<span class="nb">print</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">format_query_table</span><span class="p">(</span><span class="n">connection</span><span class="p">,</span> <span class="n">query</span><span class="p">,</span> <span class="n">bindings</span><span class="p">))</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">┌────────────┬────────────────────────────────┬───────────────┐</span>
<span class="go">│ date │ directory │ name │</span>
<span class="go">│ 2024-04-16 │ /usr/lib/python3.12/pydoc_data │ topics.py │</span>
<span class="go">│ 2024-04-16 │ /usr/lib/python3.12 │ _pydecimal.py │</span>
<span class="go">│ 2024-04-16 │ /usr/lib/python3.12/tkinter │ __init__.py │</span>
<span class="go">└────────────┴────────────────────────────────┴───────────────┘</span>
</pre></div>
</div>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># find space used by filename extension</span>
<span class="n">query</span> <span class="o">=</span> <span class="s2">"""SELECT extension, SUM(st_size) as total_size</span>
<span class="s2"> FROM files_info(?)</span>
<span class="s2"> GROUP BY extension</span>
<span class="s2"> ORDER BY extension"""</span>
<span class="nb">print</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">format_query_table</span><span class="p">(</span><span class="n">connection</span><span class="p">,</span> <span class="n">query</span><span class="p">,</span> <span class="n">bindings</span><span class="p">))</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">┌────────────┬────────────┐</span>
<span class="go">│ extension │ total_size │</span>
<span class="go">│ │ 432392 │</span>
<span class="go">│ .a │ 96832334 │</span>
<span class="go">│ .allowlist │ 56 │</span>
<span class="go">│ .bootstrap │ 1804 │</span>
<span class="go">│ .c │ 10948 │</span>
<span class="go">│ .cfg │ 341 │</span>
<span class="go">│ .csh │ 936 │</span>
<span class="go">│ .css │ 1325 │</span>
<span class="go">│ .fish │ 2215 │</span>
<span class="go">│ .in │ 3504 │</span>
<span class="go">│ .ini │ 997 │</span>
<span class="go">│ .json │ 2162 │</span>
<span class="go">│ .local │ 2136 │</span>
<span class="go">│ .o │ 9328 │</span>
<span class="go">│ .ps1 │ 9033 │</span>
<span class="go">│ .py │ 11139559 │</span>
<span class="go">│ .pyc │ 11417126 │</span>
<span class="go">│ .rst │ 9561 │</span>
<span class="go">│ .sh │ 4008 │</span>
<span class="go">│ .so │ 25379792 │</span>
<span class="go">│ .stdlib │ 12536 │</span>
<span class="go">│ .supp │ 70 │</span>
<span class="go">│ .txt │ 13936 │</span>
<span class="go">└────────────┴────────────┘</span>
</pre></div>
</div>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># unregister a virtual table by passing None</span>
<span class="n">connection</span><span class="o">.</span><span class="n">create_module</span><span class="p">(</span><span class="s2">"files_info"</span><span class="p">,</span> <span class="kc">None</span><span class="p">)</span>
</pre></div>
</div>
</section>
<section id="vfs-virtual-file-system">
<span id="example-vfs"></span><span id="index-28"></span><h2>VFS - Virtual File System<a class="headerlink" href="#vfs-virtual-file-system" title="Link to this heading"></a></h2>
<p><a class="reference internal" href="vfs.html#vfs"><span class="std std-ref">VFS</span></a> lets you control how SQLite accesses storage. APSW
makes it easy to “inherit” from an existing VFS and monitor or alter
data as it flows through.</p>
<p><a class="reference internal" href="vfs.html#apsw.URIFilename" title="apsw.URIFilename"><code class="xref py py-class docutils literal notranslate"><span class="pre">URI</span></code></a> are shown as a way to receive parameters
when opening/creating a database file, and <a class="reference internal" href="vfs.html#apsw.VFSFcntlPragma" title="apsw.VFSFcntlPragma"><code class="xref py py-class docutils literal notranslate"><span class="pre">pragmas</span></code></a>
for receiving parameters once a database is open.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># This example VFS obfuscates the database file contents by xor all</span>
<span class="c1"># bytes with 0xa5.</span>
<span class="k">def</span> <span class="nf">obfuscate</span><span class="p">(</span><span class="n">data</span><span class="p">:</span> <span class="nb">bytes</span><span class="p">):</span>
<span class="k">return</span> <span class="nb">bytes</span><span class="p">([</span><span class="n">x</span> <span class="o">^</span> <span class="mh">0xA5</span> <span class="k">for</span> <span class="n">x</span> <span class="ow">in</span> <span class="n">data</span><span class="p">])</span>
<span class="c1"># Inheriting from a base of "" means the default vfs</span>
<span class="k">class</span> <span class="nc">ObfuscatedVFS</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">VFS</span><span class="p">):</span>
<span class="k">def</span> <span class="fm">__init__</span><span class="p">(</span><span class="bp">self</span><span class="p">,</span> <span class="n">vfsname</span><span class="o">=</span><span class="s2">"obfuscated"</span><span class="p">,</span> <span class="n">basevfs</span><span class="o">=</span><span class="s2">""</span><span class="p">):</span>
<span class="bp">self</span><span class="o">.</span><span class="n">vfs_name</span> <span class="o">=</span> <span class="n">vfsname</span>
<span class="bp">self</span><span class="o">.</span><span class="n">base_vfs</span> <span class="o">=</span> <span class="n">basevfs</span>
<span class="nb">super</span><span class="p">()</span><span class="o">.</span><span class="fm">__init__</span><span class="p">(</span><span class="bp">self</span><span class="o">.</span><span class="n">vfs_name</span><span class="p">,</span> <span class="bp">self</span><span class="o">.</span><span class="n">base_vfs</span><span class="p">)</span>
<span class="c1"># We want to return our own file implementation, but also</span>
<span class="c1"># want it to inherit</span>
<span class="k">def</span> <span class="nf">xOpen</span><span class="p">(</span><span class="bp">self</span><span class="p">,</span> <span class="n">name</span><span class="p">,</span> <span class="n">flags</span><span class="p">):</span>
<span class="n">in_flags</span> <span class="o">=</span> <span class="p">[]</span>
<span class="k">for</span> <span class="n">k</span><span class="p">,</span> <span class="n">v</span> <span class="ow">in</span> <span class="n">apsw</span><span class="o">.</span><span class="n">mapping_open_flags</span><span class="o">.</span><span class="n">items</span><span class="p">():</span>
<span class="k">if</span> <span class="nb">isinstance</span><span class="p">(</span><span class="n">k</span><span class="p">,</span> <span class="nb">int</span><span class="p">)</span> <span class="ow">and</span> <span class="n">flags</span><span class="p">[</span><span class="mi">0</span><span class="p">]</span> <span class="o">&</span> <span class="n">k</span><span class="p">:</span>
<span class="n">in_flags</span><span class="o">.</span><span class="n">append</span><span class="p">(</span><span class="n">v</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"xOpen flags"</span><span class="p">,</span> <span class="s2">" | "</span><span class="o">.</span><span class="n">join</span><span class="p">(</span><span class="n">in_flags</span><span class="p">))</span>
<span class="k">if</span> <span class="nb">isinstance</span><span class="p">(</span><span class="n">name</span><span class="p">,</span> <span class="n">apsw</span><span class="o">.</span><span class="n">URIFilename</span><span class="p">):</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">" uri filename"</span><span class="p">,</span> <span class="n">name</span><span class="o">.</span><span class="n">filename</span><span class="p">())</span>
<span class="c1"># We can look at uri parameters</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">" fast is"</span><span class="p">,</span> <span class="n">name</span><span class="o">.</span><span class="n">uri_parameter</span><span class="p">(</span><span class="s2">"fast"</span><span class="p">))</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">" level is"</span><span class="p">,</span> <span class="n">name</span><span class="o">.</span><span class="n">uri_int</span><span class="p">(</span><span class="s2">"level"</span><span class="p">,</span> <span class="mi">3</span><span class="p">))</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">" warp is"</span><span class="p">,</span> <span class="n">name</span><span class="o">.</span><span class="n">uri_boolean</span><span class="p">(</span><span class="s2">"warp"</span><span class="p">,</span> <span class="kc">False</span><span class="p">))</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">" notpresent is"</span><span class="p">,</span> <span class="n">name</span><span class="o">.</span><span class="n">uri_parameter</span><span class="p">(</span><span class="s2">"notpresent"</span><span class="p">))</span>
<span class="c1"># all of them</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">" all uris"</span><span class="p">,</span> <span class="n">name</span><span class="o">.</span><span class="n">parameters</span><span class="p">)</span>
<span class="k">else</span><span class="p">:</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">" filename"</span><span class="p">,</span> <span class="n">name</span><span class="p">)</span>
<span class="k">return</span> <span class="n">ObfuscatedVFSFile</span><span class="p">(</span><span class="bp">self</span><span class="o">.</span><span class="n">base_vfs</span><span class="p">,</span> <span class="n">name</span><span class="p">,</span> <span class="n">flags</span><span class="p">)</span>
<span class="c1"># The file implementation where we override xRead and xWrite to call our</span>
<span class="c1"># encryption routine</span>
<span class="k">class</span> <span class="nc">ObfuscatedVFSFile</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">VFSFile</span><span class="p">):</span>
<span class="k">def</span> <span class="fm">__init__</span><span class="p">(</span><span class="bp">self</span><span class="p">,</span> <span class="n">inheritfromvfsname</span><span class="p">,</span> <span class="n">filename</span><span class="p">,</span> <span class="n">flags</span><span class="p">):</span>
<span class="nb">super</span><span class="p">()</span><span class="o">.</span><span class="fm">__init__</span><span class="p">(</span><span class="n">inheritfromvfsname</span><span class="p">,</span> <span class="n">filename</span><span class="p">,</span> <span class="n">flags</span><span class="p">)</span>
<span class="k">def</span> <span class="nf">xRead</span><span class="p">(</span><span class="bp">self</span><span class="p">,</span> <span class="n">amount</span><span class="p">,</span> <span class="n">offset</span><span class="p">):</span>
<span class="k">return</span> <span class="n">obfuscate</span><span class="p">(</span><span class="nb">super</span><span class="p">()</span><span class="o">.</span><span class="n">xRead</span><span class="p">(</span><span class="n">amount</span><span class="p">,</span> <span class="n">offset</span><span class="p">))</span>
<span class="k">def</span> <span class="nf">xWrite</span><span class="p">(</span><span class="bp">self</span><span class="p">,</span> <span class="n">data</span><span class="p">,</span> <span class="n">offset</span><span class="p">):</span>
<span class="nb">super</span><span class="p">()</span><span class="o">.</span><span class="n">xWrite</span><span class="p">(</span><span class="n">obfuscate</span><span class="p">(</span><span class="n">data</span><span class="p">),</span> <span class="n">offset</span><span class="p">)</span>
<span class="k">def</span> <span class="nf">xFileControl</span><span class="p">(</span><span class="bp">self</span><span class="p">,</span> <span class="n">op</span><span class="p">:</span> <span class="nb">int</span><span class="p">,</span> <span class="n">ptr</span><span class="p">:</span> <span class="nb">int</span><span class="p">)</span> <span class="o">-></span> <span class="nb">bool</span><span class="p">:</span>
<span class="k">if</span> <span class="n">op</span> <span class="o">!=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_FCNTL_PRAGMA</span><span class="p">:</span>
<span class="k">return</span> <span class="nb">super</span><span class="p">()</span><span class="o">.</span><span class="n">xFileControl</span><span class="p">(</span><span class="n">op</span><span class="p">,</span> <span class="n">ptr</span><span class="p">)</span>
<span class="c1"># implement our own pragma</span>
<span class="n">p</span> <span class="o">=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">VFSFcntlPragma</span><span class="p">(</span><span class="n">ptr</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="sa">f</span><span class="s2">"pragma received </span><span class="si">{</span><span class="w"> </span><span class="n">p</span><span class="o">.</span><span class="n">name</span><span class="w"> </span><span class="si">}</span><span class="s2"> = </span><span class="si">{</span><span class="w"> </span><span class="n">p</span><span class="o">.</span><span class="n">value</span><span class="w"> </span><span class="si">}</span><span class="s2">"</span><span class="p">)</span>
<span class="c1"># what do we understand?</span>
<span class="k">if</span> <span class="n">p</span><span class="o">.</span><span class="n">name</span> <span class="o">==</span> <span class="s2">"my_custom_pragma"</span><span class="p">:</span>
<span class="n">p</span><span class="o">.</span><span class="n">result</span> <span class="o">=</span> <span class="s2">"orange"</span>
<span class="k">return</span> <span class="kc">True</span>
<span class="c1"># We did not understand</span>
<span class="k">return</span> <span class="kc">False</span>
<span class="c1"># To register the VFS we just instantiate it</span>
<span class="n">obfuvfs</span> <span class="o">=</span> <span class="n">ObfuscatedVFS</span><span class="p">()</span>
<span class="c1"># Lets see what vfs are now available?</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"VFS available"</span><span class="p">,</span> <span class="n">apsw</span><span class="o">.</span><span class="n">vfs_names</span><span class="p">())</span>
<span class="c1"># Make an obfuscated db, passing in some URI parameters</span>
<span class="c1"># default open flags</span>
<span class="n">open_flags</span> <span class="o">=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_OPEN_READWRITE</span> <span class="o">|</span> <span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_OPEN_CREATE</span>
<span class="c1"># add in using URI parameters</span>
<span class="n">open_flags</span> <span class="o">|=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_OPEN_URI</span>
<span class="c1"># uri parameters are after the ? separated by &</span>
<span class="n">obfudb</span> <span class="o">=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">Connection</span><span class="p">(</span>
<span class="s2">"file:myobfudb?fast=speed&level=7&warp=on&another=true"</span><span class="p">,</span> <span class="n">flags</span><span class="o">=</span><span class="n">open_flags</span><span class="p">,</span> <span class="n">vfs</span><span class="o">=</span><span class="n">obfuvfs</span><span class="o">.</span><span class="n">vfs_name</span>
<span class="p">)</span>
<span class="c1"># Check it works</span>
<span class="n">obfudb</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"create table foo(x,y); insert into foo values(1,2)"</span><span class="p">)</span>
<span class="c1"># Check it really is obfuscated on disk</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"What is on disk"</span><span class="p">,</span> <span class="nb">repr</span><span class="p">(</span><span class="n">Path</span><span class="p">(</span><span class="s2">"myobfudb"</span><span class="p">)</span><span class="o">.</span><span class="n">read_bytes</span><span class="p">()[:</span><span class="mi">20</span><span class="p">]))</span>
<span class="c1"># And unobfuscating it</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"Unobfuscated disk"</span><span class="p">,</span> <span class="nb">repr</span><span class="p">(</span><span class="n">obfuscate</span><span class="p">(</span><span class="n">Path</span><span class="p">(</span><span class="s2">"myobfudb"</span><span class="p">)</span><span class="o">.</span><span class="n">read_bytes</span><span class="p">()[:</span><span class="mi">20</span><span class="p">])))</span>
<span class="c1"># Custom pragma</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"pragma returned"</span><span class="p">,</span> <span class="n">obfudb</span><span class="o">.</span><span class="n">pragma</span><span class="p">(</span><span class="s2">"my_custom_pragma"</span><span class="p">,</span> <span class="s2">"my value"</span><span class="p">))</span>
<span class="c1"># Tidy up</span>
<span class="n">obfudb</span><span class="o">.</span><span class="n">close</span><span class="p">()</span>
<span class="n">os</span><span class="o">.</span><span class="n">remove</span><span class="p">(</span><span class="s2">"myobfudb"</span><span class="p">)</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">VFS available ['unix', 'obfuscated', 'memdb', 'unix-excl', 'unix-dotfile', 'unix-none']</span>
<span class="go">xOpen flags SQLITE_OPEN_CREATE | SQLITE_OPEN_MAIN_DB | SQLITE_OPEN_READWRITE | SQLITE_OPEN_URI</span>
<span class="go"> uri filename /space/apsw-master/myobfudb</span>
<span class="go"> fast is speed</span>
<span class="go"> level is 7</span>
<span class="go"> warp is True</span>
<span class="go"> notpresent is None</span>
<span class="go"> all uris ('fast', 'level', 'warp', 'another')</span>
<span class="go">pragma received journal_mode = wal</span>
<span class="go">xOpen flags SQLITE_OPEN_CREATE | SQLITE_OPEN_MAIN_JOURNAL | SQLITE_OPEN_READWRITE</span>
<span class="go"> filename /space/apsw-master/myobfudb-journal</span>
<span class="go">pragma received foreign_keys = ON</span>
<span class="go">xOpen flags SQLITE_OPEN_CREATE | SQLITE_OPEN_READWRITE | SQLITE_OPEN_WAL</span>
<span class="go"> filename /space/apsw-master/myobfudb-wal</span>
<span class="go">What is on disk b'\xf6\xf4\xe9\xcc\xd1\xc0\x85\xc3\xca\xd7\xc8\xc4\xd1\x85\x96\xa5\xb5\xa5\xa7\xa7'</span>
<span class="go">Unobfuscated disk b'SQLite format 3\x00\x10\x00\x02\x02'</span>
<span class="go">pragma received my_custom_pragma = my value</span>
<span class="go">pragma returned orange</span>
</pre></div>
</div>
</section>
<section id="limits">
<span id="example-limits"></span><span id="index-29"></span><h2>Limits<a class="headerlink" href="#limits" title="Link to this heading"></a></h2>
<p>SQLite lets you see and update various limits via
<a class="reference internal" href="connection.html#apsw.Connection.limit" title="apsw.Connection.limit"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.limit()</span></code></a></p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># Print some limits</span>
<span class="k">for</span> <span class="n">limit</span> <span class="ow">in</span> <span class="p">(</span><span class="s2">"LENGTH"</span><span class="p">,</span> <span class="s2">"COLUMN"</span><span class="p">,</span> <span class="s2">"ATTACHED"</span><span class="p">):</span>
<span class="n">name</span> <span class="o">=</span> <span class="s2">"SQLITE_LIMIT_"</span> <span class="o">+</span> <span class="n">limit</span>
<span class="n">max_name</span> <span class="o">=</span> <span class="s2">"SQLITE_MAX_"</span> <span class="o">+</span> <span class="n">limit</span> <span class="c1"># compile time limit</span>
<span class="n">orig</span> <span class="o">=</span> <span class="n">connection</span><span class="o">.</span><span class="n">limit</span><span class="p">(</span><span class="nb">getattr</span><span class="p">(</span><span class="n">apsw</span><span class="p">,</span> <span class="n">name</span><span class="p">))</span>
<span class="nb">print</span><span class="p">(</span><span class="n">name</span><span class="p">,</span> <span class="n">orig</span><span class="p">)</span>
<span class="c1"># To get the maximum, set to 0x7fffffff and then read value back</span>
<span class="n">connection</span><span class="o">.</span><span class="n">limit</span><span class="p">(</span><span class="nb">getattr</span><span class="p">(</span><span class="n">apsw</span><span class="p">,</span> <span class="n">name</span><span class="p">),</span> <span class="mh">0x7FFFFFFF</span><span class="p">)</span>
<span class="nb">max</span> <span class="o">=</span> <span class="n">connection</span><span class="o">.</span><span class="n">limit</span><span class="p">(</span><span class="nb">getattr</span><span class="p">(</span><span class="n">apsw</span><span class="p">,</span> <span class="n">name</span><span class="p">))</span>
<span class="nb">print</span><span class="p">(</span><span class="n">max_name</span><span class="p">,</span> <span class="s2">" "</span><span class="p">,</span> <span class="nb">max</span><span class="p">)</span>
<span class="c1"># Set limit for size of a string</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"create table testlimit(s)"</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into testlimit values(?)"</span><span class="p">,</span> <span class="p">(</span><span class="s2">"x"</span> <span class="o">*</span> <span class="mi">1024</span><span class="p">,))</span> <span class="c1"># 1024 char string</span>
<span class="n">connection</span><span class="o">.</span><span class="n">limit</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_LIMIT_LENGTH</span><span class="p">,</span> <span class="mi">1023</span><span class="p">)</span> <span class="c1"># limit is now 1023</span>
<span class="k">try</span><span class="p">:</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">"insert into testlimit values(?)"</span><span class="p">,</span> <span class="p">(</span><span class="s2">"y"</span> <span class="o">*</span> <span class="mi">1024</span><span class="p">,))</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"string exceeding limit was inserted"</span><span class="p">)</span>
<span class="k">except</span> <span class="n">apsw</span><span class="o">.</span><span class="n">TooBigError</span><span class="p">:</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"Caught toobig exception"</span><span class="p">)</span>
<span class="c1"># reset back to largest value</span>
<span class="n">connection</span><span class="o">.</span><span class="n">limit</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_LIMIT_LENGTH</span><span class="p">,</span> <span class="mh">0x7FFFFFFF</span><span class="p">)</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">SQLITE_LIMIT_LENGTH 1000000000</span>
<span class="go">SQLITE_MAX_LENGTH 1000000000</span>
<span class="go">SQLITE_LIMIT_COLUMN 2000</span>
<span class="go">SQLITE_MAX_COLUMN 2000</span>
<span class="go">SQLITE_LIMIT_ATTACHED 125</span>
<span class="go">SQLITE_MAX_ATTACHED 125</span>
<span class="go">Caught toobig exception</span>
</pre></div>
</div>
</section>
<section id="shell">
<span id="example-shell"></span><span id="index-30"></span><h2>Shell<a class="headerlink" href="#shell" title="Link to this heading"></a></h2>
<p>APSW includes a <a class="reference internal" href="shell.html#shell"><span class="std std-ref">shell</span></a> like the one in <a class="reference external" href="https://sqlite.org/cli.html">SQLite</a>, and is also extensible from
Python.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="kn">import</span> <span class="nn">apsw.shell</span>
<span class="c1"># Here we use the shell to do a csv export and then dump part of the</span>
<span class="c1"># database</span>
<span class="c1"># Export to a StringIO</span>
<span class="kn">import</span> <span class="nn">io</span>
<span class="n">output</span> <span class="o">=</span> <span class="n">io</span><span class="o">.</span><span class="n">StringIO</span><span class="p">()</span>
<span class="n">shell</span> <span class="o">=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">shell</span><span class="o">.</span><span class="n">Shell</span><span class="p">(</span><span class="n">stdout</span><span class="o">=</span><span class="n">output</span><span class="p">,</span> <span class="n">db</span><span class="o">=</span><span class="n">connection</span><span class="p">)</span>
<span class="c1"># How to execute a dot command</span>
<span class="n">shell</span><span class="o">.</span><span class="n">process_command</span><span class="p">(</span><span class="s2">".mode csv"</span><span class="p">)</span>
<span class="n">shell</span><span class="o">.</span><span class="n">process_command</span><span class="p">(</span><span class="s2">".headers on"</span><span class="p">)</span>
<span class="c1"># How to execute SQL</span>
<span class="n">shell</span><span class="o">.</span><span class="n">process_sql</span><span class="p">(</span><span class="s2">"""</span>
<span class="s2"> create table csvtest(column1, column2 INTEGER);</span>
<span class="s2"> create index faster on csvtest(column1);</span>
<span class="s2"> insert into csvtest values(3, 4);</span>
<span class="s2"> insert into csvtest values('a b', NULL);</span>
<span class="s2">"""</span><span class="p">)</span>
<span class="c1"># Or let the shell figure out SQL vs dot command</span>
<span class="n">shell</span><span class="o">.</span><span class="n">process_complete_line</span><span class="p">(</span><span class="s2">"select * from csvtest"</span><span class="p">)</span>
<span class="c1"># see the result</span>
<span class="nb">print</span><span class="p">(</span><span class="n">output</span><span class="o">.</span><span class="n">getvalue</span><span class="p">())</span>
<span class="c1"># reset output</span>
<span class="n">output</span><span class="o">.</span><span class="n">seek</span><span class="p">(</span><span class="mi">0</span><span class="p">)</span>
<span class="c1"># make a dump of the same table</span>
<span class="n">shell</span><span class="o">.</span><span class="n">process_command</span><span class="p">(</span><span class="s2">".dump csvtest%"</span><span class="p">)</span>
<span class="c1"># see the result</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"</span><span class="se">\n</span><span class="s2">Dump output</span><span class="se">\n</span><span class="s2">"</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="n">output</span><span class="o">.</span><span class="n">getvalue</span><span class="p">())</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">column1,column2</span>
<span class="go">3,4</span>
<span class="go">a b,</span>
<span class="go">Dump output</span>
<span class="go">-- SQLite dump (by APSW 3.46.0.1)</span>
<span class="go">-- SQLite version 3.46.0</span>
<span class="go">-- Date: Sun Jun 16 12:43:00 2024</span>
<span class="go">-- Tables like: csvtest%</span>
<span class="go">-- Database: /space/apsw-master/dbfile</span>
<span class="go">-- User: rogerb @ clamps</span>
<span class="go">-- The values of various per-database settings</span>
<span class="go">PRAGMA page_size=4096;</span>
<span class="go">-- PRAGMA encoding='UTF-8';</span>
<span class="go">-- PRAGMA auto_vacuum=NONE;</span>
<span class="go">-- PRAGMA max_page_count=4294967294;</span>
<span class="go">BEGIN TRANSACTION;</span>
<span class="go">-- Table csvtest</span>
<span class="go">DROP TABLE IF EXISTS csvtest;</span>
<span class="go">CREATE TABLE csvtest(column1, column2 INTEGER);</span>
<span class="go">INSERT INTO csvtest VALUES(3,4);</span>
<span class="go">INSERT INTO csvtest VALUES('a b',NULL);</span>
<span class="go">-- Triggers and indices on csvtest</span>
<span class="go">CREATE INDEX faster on csvtest(column1);</span>
<span class="go">-- Your database may need this. It is sometimes used to keep track of the</span>
<span class="go">-- schema version.</span>
<span class="go">pragma user_version=1234;</span>
<span class="go">COMMIT TRANSACTION;</span>
</pre></div>
</div>
</section>
<section id="statistics">
<span id="example-status"></span><span id="index-31"></span><h2>Statistics<a class="headerlink" href="#statistics" title="Link to this heading"></a></h2>
<p>SQLite provides statistics by <a class="reference internal" href="apsw.html#apsw.status" title="apsw.status"><code class="xref py py-meth docutils literal notranslate"><span class="pre">status()</span></code></a>. Use <a class="reference internal" href="connection.html#apsw.Connection.status" title="apsw.Connection.status"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.status()</span></code></a>
for per connection statistics.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="n">current_usage</span><span class="p">,</span> <span class="n">max_usage</span> <span class="o">=</span> <span class="n">apsw</span><span class="o">.</span><span class="n">status</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_STATUS_MEMORY_USED</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="sa">f</span><span class="s2">"SQLite memory usage </span><span class="si">{</span><span class="w"> </span><span class="n">current_usage</span><span class="w"> </span><span class="si">}</span><span class="s2"> max </span><span class="si">{</span><span class="w"> </span><span class="n">max_usage</span><span class="w"> </span><span class="si">}</span><span class="s2">"</span><span class="p">)</span>
<span class="n">schema_used</span><span class="p">,</span> <span class="n">_</span> <span class="o">=</span> <span class="n">connection</span><span class="o">.</span><span class="n">status</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_DBSTATUS_SCHEMA_USED</span><span class="p">)</span>
<span class="nb">print</span><span class="p">(</span><span class="sa">f</span><span class="s2">"</span><span class="si">{</span><span class="w"> </span><span class="n">schema_used</span><span class="w"> </span><span class="si">}</span><span class="s2"> bytes used to store schema for this connection"</span><span class="p">)</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">SQLite memory usage 509352 max 2494520</span>
<span class="go">4968 bytes used to store schema for this connection</span>
</pre></div>
</div>
</section>
<section id="tracing">
<span id="example-trace-v2"></span><span id="index-32"></span><h2>Tracing<a class="headerlink" href="#tracing" title="Link to this heading"></a></h2>
<p>This shows using <a class="reference internal" href="connection.html#apsw.Connection.trace_v2" title="apsw.Connection.trace_v2"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.trace_v2()</span></code></a></p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># From https://www.sqlite.org/lang_with.html</span>
<span class="c1"># Outlandish Recursive Query Examples</span>
<span class="n">query</span> <span class="o">=</span> <span class="s2">"""WITH RECURSIVE</span>
<span class="s2"> xaxis(x) AS (VALUES(-2.0) UNION ALL SELECT x+0.05 FROM xaxis WHERE x<1.2),</span>
<span class="s2"> yaxis(y) AS (VALUES(-1.0) UNION ALL SELECT y+0.1 FROM yaxis WHERE y<1.0),</span>
<span class="s2"> m(iter, cx, cy, x, y) AS (</span>
<span class="s2"> SELECT 0, x, y, 0.0, 0.0 FROM xaxis, yaxis</span>
<span class="s2"> UNION ALL</span>
<span class="s2"> SELECT iter+1, cx, cy, x*x-y*y + cx, 2.0*x*y + cy FROM m</span>
<span class="s2"> WHERE (x*x + y*y) < 4.0 AND iter<28</span>
<span class="s2"> ),</span>
<span class="s2"> m2(iter, cx, cy) AS (</span>
<span class="s2"> SELECT max(iter), cx, cy FROM m GROUP BY cx, cy</span>
<span class="s2"> ),</span>
<span class="s2"> a(t) AS (</span>
<span class="s2"> SELECT group_concat( substr(' .+*#', 1+min(iter/7,4), 1), '')</span>
<span class="s2"> FROM m2 GROUP BY cy</span>
<span class="s2"> )</span>
<span class="s2"> SELECT group_concat(rtrim(t),x'0a') FROM a;"""</span>
<span class="k">def</span> <span class="nf">trace_hook</span><span class="p">(</span><span class="n">trace</span><span class="p">:</span> <span class="nb">dict</span><span class="p">)</span> <span class="o">-></span> <span class="kc">None</span><span class="p">:</span>
<span class="c1"># check the sql and connection are as expected and remove from trace</span>
<span class="c1"># so we don't print them</span>
<span class="k">assert</span> <span class="n">trace</span><span class="o">.</span><span class="n">pop</span><span class="p">(</span><span class="s2">"sql"</span><span class="p">)</span> <span class="o">==</span> <span class="n">query</span> <span class="ow">and</span> <span class="n">trace</span><span class="o">.</span><span class="n">pop</span><span class="p">(</span><span class="s2">"connection"</span><span class="p">)</span> <span class="ow">is</span> <span class="n">connection</span>
<span class="nb">print</span><span class="p">(</span><span class="s2">"code is "</span><span class="p">,</span> <span class="n">apsw</span><span class="o">.</span><span class="n">mapping_trace_codes</span><span class="p">[</span><span class="n">trace</span><span class="p">[</span><span class="s2">"code"</span><span class="p">]])</span>
<span class="nb">print</span><span class="p">(</span><span class="n">pprint</span><span class="o">.</span><span class="n">pformat</span><span class="p">(</span><span class="n">trace</span><span class="p">),</span> <span class="s2">"</span><span class="se">\n</span><span class="s2">"</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">trace_v2</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_TRACE_STMT</span> <span class="o">|</span> <span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_TRACE_PROFILE</span> <span class="o">|</span> <span class="n">apsw</span><span class="o">.</span><span class="n">SQLITE_TRACE_ROW</span><span class="p">,</span> <span class="n">trace_hook</span><span class="p">)</span>
<span class="c1"># We will get one each of the trace events</span>
<span class="k">for</span> <span class="n">_</span> <span class="ow">in</span> <span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="n">query</span><span class="p">):</span>
<span class="k">pass</span>
<span class="c1"># Turn off tracing</span>
<span class="n">connection</span><span class="o">.</span><span class="n">trace_v2</span><span class="p">(</span><span class="mi">0</span><span class="p">,</span> <span class="kc">None</span><span class="p">)</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">code is SQLITE_TRACE_STMT</span>
<span class="go">{'code': 1}</span>
<span class="go">code is SQLITE_TRACE_ROW</span>
<span class="go">{'code': 4}</span>
<span class="go">code is SQLITE_TRACE_PROFILE</span>
<span class="go">{'code': 2,</span>
<span class="go"> 'nanoseconds': 20000000,</span>
<span class="go"> 'stmt_status': {'SQLITE_STMTSTATUS_AUTOINDEX': 0,</span>
<span class="go"> 'SQLITE_STMTSTATUS_FILTER_HIT': 0,</span>
<span class="go"> 'SQLITE_STMTSTATUS_FILTER_MISS': 0,</span>
<span class="go"> 'SQLITE_STMTSTATUS_FULLSCAN_STEP': 1365,</span>
<span class="go"> 'SQLITE_STMTSTATUS_MEMUSED': 15784,</span>
<span class="go"> 'SQLITE_STMTSTATUS_REPREPARE': 0,</span>
<span class="go"> 'SQLITE_STMTSTATUS_RUN': 1,</span>
<span class="go"> 'SQLITE_STMTSTATUS_SORT': 2,</span>
<span class="go"> 'SQLITE_STMTSTATUS_VM_STEP': 1015351}}</span>
</pre></div>
</div>
</section>
<section id="formatting-query-results-table">
<span id="example-format-query"></span><span id="index-33"></span><h2>Formatting query results table<a class="headerlink" href="#formatting-query-results-table" title="Link to this heading"></a></h2>
<p><a class="reference internal" href="ext.html#apsw.ext.format_query_table" title="apsw.ext.format_query_table"><code class="xref py py-meth docutils literal notranslate"><span class="pre">apsw.ext.format_query_table()</span></code></a> makes it easy
to format the results of a query in an automatic
adjusting table, colour, sanitizing strings,
truncation etc.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># Create a table with some dummy data</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span>
<span class="w"> </span><span class="sd">"""CREATE TABLE dummy(quantity, [spaces in name], last);</span>
<span class="sd"> INSERT INTO dummy VALUES(3, 'some regular text to make this row interesting', x'030709');</span>
<span class="sd"> INSERT INTO dummy VALUES(3.14, 'Tiếng Việt', null);</span>
<span class="sd"> INSERT INTO dummy VALUES('', ?, ' ');</span>
<span class="sd">"""</span><span class="p">,</span>
<span class="p">(</span><span class="s2">"special </span><span class="se">\t\n\f\0</span><span class="s2"> cha</span><span class="se">\\</span><span class="s2">rs"</span><span class="p">,),</span>
<span class="p">)</span>
<span class="n">query</span> <span class="o">=</span> <span class="s2">"SELECT * FROM dummy"</span>
<span class="c1"># default</span>
<span class="nb">print</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">format_query_table</span><span class="p">(</span><span class="n">connection</span><span class="p">,</span> <span class="n">query</span><span class="p">))</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">┌───────┬─────────────────────────────────────────────────────────────┬────────┐</span>
<span class="go">│ quant │ spaces in name │ last │</span>
<span class="go">│ ity │ │ │</span>
<span class="go">├───────┼─────────────────────────────────────────────────────────────┼────────┤</span>
<span class="go">│ 3 │ some regular text to make this row interesting │ [ 3 │</span>
<span class="go">│ │ │ bytes │</span>
<span class="go">│ │ │ ] │</span>
<span class="go">├───────┼─────────────────────────────────────────────────────────────┼────────┤</span>
<span class="go">│ 3.14 │ Ti{LATIN SMALL LETTER E WITH CIRCUMFLEX AND ACUTE}ng │ (null) │</span>
<span class="go">│ │ Vi{LATIN SMALL LETTER E WITH CIRCUMFLEX AND DOT BELOW}t │ │</span>
<span class="go">├───────┼─────────────────────────────────────────────────────────────┼────────┤</span>
<span class="go">│ │ special │ │</span>
<span class="go">│ │ \0 cha\\rs │ │</span>
<span class="go">└───────┴─────────────────────────────────────────────────────────────┴────────┘</span>
</pre></div>
</div>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># no unicode boxes and maximum sanitize the text</span>
<span class="n">kwargs</span> <span class="o">=</span> <span class="p">{</span><span class="s2">"use_unicode"</span><span class="p">:</span> <span class="kc">False</span><span class="p">,</span> <span class="s2">"string_sanitize"</span><span class="p">:</span> <span class="mi">2</span><span class="p">}</span>
<span class="nb">print</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">format_query_table</span><span class="p">(</span><span class="n">connection</span><span class="p">,</span> <span class="n">query</span><span class="p">,</span> <span class="o">**</span><span class="n">kwargs</span><span class="p">))</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">+----------+------------------------------------------------+-------------+</span>
<span class="go">| quantity | spaces in name | last |</span>
<span class="go">+----------+------------------------------------------------+-------------+</span>
<span class="go">| 3 | some.regular.text.to.make.this.row.interesting | [ 3 bytes ] |</span>
<span class="go">+----------+------------------------------------------------+-------------+</span>
<span class="go">| 3.14 | Ti.ng.Vi.t | (null) |</span>
<span class="go">+----------+------------------------------------------------+-------------+</span>
<span class="go">| | special.. | . |</span>
<span class="go">| | ...cha\rs | |</span>
<span class="go">+----------+------------------------------------------------+-------------+</span>
</pre></div>
</div>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># lets have unicode boxes and make things narrow with no word wrap</span>
<span class="n">kwargs</span> <span class="o">=</span> <span class="p">{</span><span class="s2">"use_unicode"</span><span class="p">:</span> <span class="kc">True</span><span class="p">,</span> <span class="s2">"string_sanitize"</span><span class="p">:</span> <span class="mi">0</span><span class="p">,</span> <span class="s2">"text_width"</span><span class="p">:</span> <span class="mi">30</span><span class="p">,</span> <span class="s2">"word_wrap"</span><span class="p">:</span> <span class="kc">False</span><span class="p">}</span>
<span class="nb">print</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">format_query_table</span><span class="p">(</span><span class="n">connection</span><span class="p">,</span> <span class="n">query</span><span class="p">,</span> <span class="o">**</span><span class="n">kwargs</span><span class="p">))</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">┌─────┬────────────────┬─────┐</span>
<span class="go">│ qua │ spaces in name │ las │</span>
<span class="go">│ nti │ │ t │</span>
<span class="go">│ ty │ │ │</span>
<span class="go">├─────┼────────────────┼─────┤</span>
<span class="go">│ 3 │ some regular t │ [ 3 │</span>
<span class="go">│ │ ext to make th │ by │</span>
<span class="go">│ │ is row interes │ tes │</span>
<span class="go">│ │ ting │ ] │</span>
<span class="go">├─────┼────────────────┼─────┤</span>
<span class="go">│ 3.1 │ Tiếng Việt │ (nu │</span>
<span class="go">│ 4 │ │ ll) │</span>
<span class="go">├─────┼────────────────┼─────┤</span>
<span class="go">│ │ special │ │</span>
<span class="go">│ │ \0 cha\\rs │ │</span>
<span class="go">└─────┴────────────────┴─────┘</span>
</pre></div>
</div>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># have the values in SQL syntax</span>
<span class="n">kwargs</span> <span class="o">=</span> <span class="p">{</span><span class="s2">"quote"</span><span class="p">:</span> <span class="kc">True</span><span class="p">}</span>
<span class="nb">print</span><span class="p">(</span><span class="n">apsw</span><span class="o">.</span><span class="n">ext</span><span class="o">.</span><span class="n">format_query_table</span><span class="p">(</span><span class="n">connection</span><span class="p">,</span> <span class="n">query</span><span class="p">,</span> <span class="o">**</span><span class="n">kwargs</span><span class="p">))</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">┌───────┬──────────────────────────────────────────────────────────────┬───────┐</span>
<span class="go">│ quant │ spaces in name │ last │</span>
<span class="go">│ ity │ │ │</span>
<span class="go">├───────┼──────────────────────────────────────────────────────────────┼───────┤</span>
<span class="go">│ 3 │ 'some regular text to make this row interesting' │ X'030 │</span>
<span class="go">│ │ │ 709' │</span>
<span class="go">├───────┼──────────────────────────────────────────────────────────────┼───────┤</span>
<span class="go">│ 3.14 │ 'Ti{LATIN SMALL LETTER E WITH CIRCUMFLEX AND ACUTE}ng │ NULL │</span>
<span class="go">│ │ Vi{LATIN SMALL LETTER E WITH CIRCUMFLEX AND DOT BELOW}t' │ │</span>
<span class="go">├───────┼──────────────────────────────────────────────────────────────┼───────┤</span>
<span class="go">│ '' │ 'special │ ' ' │</span>
<span class="go">│ │ \0 cha\\rs' │ │</span>
<span class="go">└───────┴──────────────────────────────────────────────────────────────┴───────┘</span>
</pre></div>
</div>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span>
</pre></div>
</div>
</section>
<section id="cleanup">
<span id="example-cleanup"></span><span id="index-34"></span><h2>Cleanup<a class="headerlink" href="#cleanup" title="Link to this heading"></a></h2>
<p>As a general rule you do not need to do any cleanup. Standard
Python garbage collection will take of everything. Even if the
process crashes with a connection in the middle of a transaction,
the next time SQLite opens that database it will automatically
rollback the incomplete transaction.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="c1"># You can close connections manually</span>
<span class="n">connection</span><span class="o">.</span><span class="n">close</span><span class="p">()</span>
</pre></div>
</div>
</section>
</section>
</div>
</div>
<footer><div class="rst-footer-buttons" role="navigation" aria-label="Footer">
<a href="tips.html" class="btn btn-neutral float-left" title="Tips" accesskey="p" rel="prev"><span class="fa fa-arrow-circle-left" aria-hidden="true"></span> Previous</a>
<a href="install.html" class="btn btn-neutral float-right" title="Installation and customization" accesskey="n" rel="next">Next <span class="fa fa-arrow-circle-right" aria-hidden="true"></span></a>
</div>
<hr/>
<div role="contentinfo">
<p>© <a href="copyright.html">Copyright</a> 2004-2024, Roger Binns <rogerb@rogerbinns.com>.
<span class="lastupdated">Last updated on Jun 16, 2024.
</span></p>
</div>
Built with <a href="https://www.sphinx-doc.org/">Sphinx</a> using a
<a href="https://github.com/readthedocs/sphinx_rtd_theme">theme</a>
provided by <a href="https://readthedocs.org">Read the Docs</a>.
</footer>
</div>
</div>
</section>
</div>
<script>
jQuery(function () {
SphinxRtdTheme.Navigation.enable(true);
});
</script>
</body>
</html>
|