1558 lines
		
	
	
		
			68 KiB
		
	
	
	
		
			HTML
		
	
	
	
	
	
			
		
		
	
	
			1558 lines
		
	
	
		
			68 KiB
		
	
	
	
		
			HTML
		
	
	
	
	
	
| <!DOCTYPE html>
 | |
| <html><head>
 | |
| <meta name="viewport" content="width=device-width, initial-scale=1.0">
 | |
| <meta http-equiv="content-type" content="text/html; charset=UTF-8">
 | |
| <link href="sqlite.css" rel="stylesheet">
 | |
| <title>Command Line Shell For SQLite</title>
 | |
| <!-- path= -->
 | |
| </head>
 | |
| <body>
 | |
| <div class=nosearch>
 | |
| <a href="index.html">
 | |
| <img class="logo" src="images/sqlite370_banner.gif" alt="SQLite" border="0">
 | |
| </a>
 | |
| <div><!-- IE hack to prevent disappearing logo --></div>
 | |
| <div class="tagline desktoponly">
 | |
| Small. Fast. Reliable.<br>Choose any three.
 | |
| </div>
 | |
| <div class="menu mainmenu">
 | |
| <ul>
 | |
| <li><a href="index.html">Home</a>
 | |
| <li class='mobileonly'><a href="javascript:void(0)" onclick='toggle_div("submenu")'>Menu</a>
 | |
| <li class='wideonly'><a href='about.html'>About</a>
 | |
| <li class='desktoponly'><a href="docs.html">Documentation</a>
 | |
| <li class='desktoponly'><a href="download.html">Download</a>
 | |
| <li class='wideonly'><a href='copyright.html'>License</a>
 | |
| <li class='desktoponly'><a href="support.html">Support</a>
 | |
| <li class='desktoponly'><a href="prosupport.html">Purchase</a>
 | |
| <li class='search' id='search_menubutton'>
 | |
| <a href="javascript:void(0)" onclick='toggle_search()'>Search</a>
 | |
| </ul>
 | |
| </div>
 | |
| <div class="menu submenu" id="submenu">
 | |
| <ul>
 | |
| <li><a href='about.html'>About</a>
 | |
| <li><a href='docs.html'>Documentation</a>
 | |
| <li><a href='download.html'>Download</a>
 | |
| <li><a href='support.html'>Support</a>
 | |
| <li><a href='prosupport.html'>Purchase</a>
 | |
| </ul>
 | |
| </div>
 | |
| <div class="searchmenu" id="searchmenu">
 | |
| <form method="GET" action="search">
 | |
| <select name="s" id="searchtype">
 | |
| <option value="d">Search Documentation</option>
 | |
| <option value="c">Search Changelog</option>
 | |
| </select>
 | |
| <input type="text" name="q" id="searchbox" value="">
 | |
| <input type="submit" value="Go">
 | |
| </form>
 | |
| </div>
 | |
| </div>
 | |
| <script>
 | |
| function toggle_div(nm) {
 | |
| var w = document.getElementById(nm);
 | |
| if( w.style.display=="block" ){
 | |
| w.style.display = "none";
 | |
| }else{
 | |
| w.style.display = "block";
 | |
| }
 | |
| }
 | |
| function toggle_search() {
 | |
| var w = document.getElementById("searchmenu");
 | |
| if( w.style.display=="block" ){
 | |
| w.style.display = "none";
 | |
| } else {
 | |
| w.style.display = "block";
 | |
| setTimeout(function(){
 | |
| document.getElementById("searchbox").focus()
 | |
| }, 30);
 | |
| }
 | |
| }
 | |
| function div_off(nm){document.getElementById(nm).style.display="none";}
 | |
| window.onbeforeunload = function(e){div_off("submenu");}
 | |
| /* Disable the Search feature if we are not operating from CGI, since */
 | |
| /* Search is accomplished using CGI and will not work without it. */
 | |
| if( !location.origin || !location.origin.match || !location.origin.match(/http/) ){
 | |
| document.getElementById("search_menubutton").style.display = "none";
 | |
| }
 | |
| /* Used by the Hide/Show button beside syntax diagrams, to toggle the */
 | |
| function hideorshow(btn,obj){
 | |
| var x = document.getElementById(obj);
 | |
| var b = document.getElementById(btn);
 | |
| if( x.style.display!='none' ){
 | |
| x.style.display = 'none';
 | |
| b.innerHTML='show';
 | |
| }else{
 | |
| x.style.display = '';
 | |
| b.innerHTML='hide';
 | |
| }
 | |
| return false;
 | |
| }
 | |
| </script>
 | |
| </div>
 | |
| <div class=fancy>
 | |
| <div class=nosearch>
 | |
| <div class="fancy_title">
 | |
| Command Line Shell For SQLite
 | |
| </div>
 | |
| <div class="fancy_toc">
 | |
| <a onclick="toggle_toc()">
 | |
| <span class="fancy_toc_mark" id="toc_mk">►</span>
 | |
| Table Of Contents
 | |
| </a>
 | |
| <div id="toc_sub"><div class="fancy-toc1"><a href="#getting_started">1. Getting Started</a></div>
 | |
| <div class="fancy-toc1"><a href="#double_click_startup_on_windows">2. Double-click Startup On Windows</a></div>
 | |
| <div class="fancy-toc1"><a href="#special_commands_to_sqlite3_dot_commands_">3. Special commands to sqlite3 (dot-commands)</a></div>
 | |
| <div class="fancy-toc1"><a href="#rules_for_dot_commands_">4. Rules for "dot-commands"</a></div>
 | |
| <div class="fancy-toc1"><a href="#changing_output_formats">5. Changing Output Formats</a></div>
 | |
| <div class="fancy-toc1"><a href="#writing_results_to_a_file">6. Writing results to a file</a></div>
 | |
| <div class="fancy-toc2"><a href="#file_i_o_functions">6.1. File I/O Functions</a></div>
 | |
| <div class="fancy-toc2"><a href="#the_edit_sql_function">6.2. The edit() SQL function</a></div>
 | |
| <div class="fancy-toc1"><a href="#querying_the_database_schema">7. Querying the database schema</a></div>
 | |
| <div class="fancy-toc1"><a href="#csv_import">8. CSV Import</a></div>
 | |
| <div class="fancy-toc1"><a href="#csv_export">9. CSV Export</a></div>
 | |
| <div class="fancy-toc2"><a href="#_export_to_excel_">9.1.  Export to Excel </a></div>
 | |
| <div class="fancy-toc1"><a href="#accessing_zip_archives_as_database_files">10. Accessing ZIP Archives As Database Files</a></div>
 | |
| <div class="fancy-toc2"><a href="#how_zip_archive_access_is_implemented">10.1. How ZIP archive access is implemented</a></div>
 | |
| <div class="fancy-toc1"><a href="#converting_an_entire_database_to_an_ascii_text_file">11. Converting An Entire Database To An ASCII Text File</a></div>
 | |
| <div class="fancy-toc1"><a href="#recover_data_from_a_corrupted_database">12. Recover Data From a Corrupted Database</a></div>
 | |
| <div class="fancy-toc1"><a href="#loading_extensions">13. Loading Extensions</a></div>
 | |
| <div class="fancy-toc1"><a href="#cryptographic_hashes_of_database_content">14. Cryptographic Hashes Of Database Content</a></div>
 | |
| <div class="fancy-toc1"><a href="#database_content_self_tests">15. Database Content Self-Tests</a></div>
 | |
| <div class="fancy-toc1"><a href="#sqlite_archive_support">16. SQLite Archive Support</a></div>
 | |
| <div class="fancy-toc2"><a href="#_sqlite_archive_create_command_">16.1.  SQLite Archive Create Command </a></div>
 | |
| <div class="fancy-toc2"><a href="#_sqlite_archive_extract_command_">16.2.  SQLite Archive Extract Command </a></div>
 | |
| <div class="fancy-toc2"><a href="#_sqlite_archive_list_command_">16.3.  SQLite Archive List Command </a></div>
 | |
| <div class="fancy-toc2"><a href="#_sqlite_archive_insert_and_update_commands_">16.4.  SQLite Archive Insert And Update Commands </a></div>
 | |
| <div class="fancy-toc2"><a href="#_operations_on_zip_archives_">16.5.  Operations On ZIP Archives </a></div>
 | |
| <div class="fancy-toc2"><a href="#_sql_used_to_implement_sqlite_archive_operations_">16.6.  SQL Used To Implement SQLite Archive Operations </a></div>
 | |
| <div class="fancy-toc1"><a href="#sql_parameters">17. SQL Parameters</a></div>
 | |
| <div class="fancy-toc1"><a href="#index_recommendations_sqlite_expert_">18. Index Recommendations (SQLite Expert)</a></div>
 | |
| <div class="fancy-toc1"><a href="#other_dot_commands">19. Other Dot Commands</a></div>
 | |
| <div class="fancy-toc1"><a href="#using_sqlite3_in_a_shell_script">20. Using sqlite3 in a shell script</a></div>
 | |
| <div class="fancy-toc1"><a href="#ending_shell_commands">21. Ending shell commands</a></div>
 | |
| <div class="fancy-toc1"><a href="#compiling_the_sqlite3_program_from_sources">22. Compiling the sqlite3 program from sources</a></div>
 | |
| <div class="fancy-toc2"><a href="#_do_it_yourself_builds_">22.1.  Do-It-Yourself Builds </a></div>
 | |
| </div>
 | |
| </div>
 | |
| <script>
 | |
| function toggle_toc(){
 | |
| var sub = document.getElementById("toc_sub")
 | |
| var mk = document.getElementById("toc_mk")
 | |
| if( sub.style.display!="block" ){
 | |
| sub.style.display = "block";
 | |
| mk.innerHTML = "▼";
 | |
| } else {
 | |
| sub.style.display = "none";
 | |
| mk.innerHTML = "►";
 | |
| }
 | |
| }
 | |
| </script>
 | |
| </div>
 | |
| 
 | |
| 
 | |
| 
 | |
| 
 | |
| <a name="intro"></a>
 | |
| 
 | |
| <h1 id="getting_started"><span>1. </span>Getting Started</h1>
 | |
| 
 | |
| <p>The SQLite project provides a simple command-line program named
 | |
| <b>sqlite3</b> (or <b>sqlite3.exe</b> on Windows)
 | |
| that allows the user to manually enter and execute SQL
 | |
| statements against an SQLite database or against a
 | |
| <a href="#zipdb">ZIP archive</a>.  This document provides a brief
 | |
| introduction on how to use the <b>sqlite3</b> program.
 | |
| 
 | |
| </p><p>Start the <b>sqlite3</b> program by typing "sqlite3" at the
 | |
| command prompt, optionally followed 
 | |
| by the name the file that holds the SQLite database
 | |
| (or <a href="#zipdb">ZIP archive</a>).  If the named
 | |
| file does not exist, a new database file with the given name will be
 | |
| created automatically.  If no database file is specified on the
 | |
| command-line, a temporary database is created, then deleted when 
 | |
| the "sqlite3" program exits.
 | |
| 
 | |
| </p><p>On startup, the <b>sqlite3</b> program will show a brief banner
 | |
| message then prompt you to enter SQL.  Type in SQL statements (terminated
 | |
| by a semicolon), press "Enter" and the SQL will be executed.</p>
 | |
| 
 | |
| <p>For example, to create a new SQLite database named "ex1" 
 | |
| with a single table named "tbl1", you might do this:</p>
 | |
| 
 | |
| <div class="codeblock"><pre>$ <b>sqlite3 ex1</b>
 | |
| SQLite version 3.28.0 2019-03-02 15:25:24
 | |
| Enter ".help" for usage hints.
 | |
| sqlite> <b>create table tbl1(one varchar(10), two smallint);</b>
 | |
| sqlite> <b>insert into tbl1 values('hello!',10);</b>
 | |
| sqlite> <b>insert into tbl1 values('goodbye', 20);</b>
 | |
| sqlite> <b>select * from tbl1;</b>
 | |
| hello!|10
 | |
| goodbye|20
 | |
| sqlite>
 | |
| </pre></div>
 | |
| 
 | |
| <p>Terminate the sqlite3 program by typing your system
 | |
| End-Of-File character (usually a Control-D).  Use the interrupt
 | |
| character (usually a Control-C) to stop a long-running SQL statement.</p>
 | |
| 
 | |
| <p>Make sure you type a semicolon at the end of each SQL command!
 | |
| The sqlite3 program looks for a semicolon to know when your SQL command is
 | |
| complete.  If you omit the semicolon, sqlite3 will give you a
 | |
| continuation prompt and wait for you to enter more text to be
 | |
| added to the current SQL command.  This feature allows you to
 | |
| enter SQL commands that span multiple lines.  For example:</p>
 | |
| 
 | |
| 
 | |
| <div class="codeblock"><pre>sqlite> <b>CREATE TABLE tbl2 (</b>
 | |
|    ...> <b>  f1 varchar(30) primary key,</b>
 | |
|    ...> <b>  f2 text,</b>
 | |
|    ...> <b>  f3 real</b>
 | |
|    ...> <b>);</b>
 | |
| sqlite>
 | |
| </pre></div>
 | |
| 
 | |
| <a name="dblclick"></a>
 | |
| 
 | |
| <h1 id="double_click_startup_on_windows"><span>2. </span>Double-click Startup On Windows</h1>
 | |
| 
 | |
| <p>Windows users can double-click on the <b>sqlite3.exe</b> icon to cause
 | |
| the command-line shell to pop-up a terminal window running SQLite.  However,
 | |
| because double-clicking starts the sqlite3.exe without command-line arguments,
 | |
| no database file will have been specified, so SQLite will use a temporary
 | |
| database that is deleted when the session exits.
 | |
| To use a persistent disk file as the database, enter the ".open" command
 | |
| immediately after the terminal window starts up:
 | |
| 
 | |
| </p><div class="codeblock"><pre>SQLite version 3.28.0 2019-03-02 15:25:24
 | |
| Enter ".help" for usage hints.
 | |
| Connected to a transient in-memory database.
 | |
| Use ".open FILENAME" to reopen on a persistent database.
 | |
| sqlite> <b>.open ex1.db</b>
 | |
| sqlite>
 | |
| </pre></div>
 | |
| 
 | |
| <p>The example above causes the database file named "ex1.db" to be opened
 | |
| and used.  The "ex1.db" file is created if it does not previously exist.
 | |
| You might want to
 | |
| use a full pathname to ensure that the file is in the directory that you
 | |
| think it is in.  Use forward-slashes as the directory separator character.
 | |
| In other words use "c:/work/ex1.db", not "c:\work\ex1.db".</p>
 | |
| 
 | |
| <p>Alternatively, you can create a new database using the default temporary
 | |
| storage, then save that database into a disk file using the ".save" command:
 | |
| 
 | |
| </p><div class="codeblock"><pre>SQLite version 3.28.0 2019-03-02 15:25:24
 | |
| Enter ".help" for usage hints.
 | |
| Connected to a transient in-memory database.
 | |
| Use ".open FILENAME" to reopen on a persistent database.
 | |
| sqlite> <i>... many SQL commands omitted ...</i>
 | |
| sqlite> <b>.save ex1.db</b>
 | |
| sqlite>
 | |
| </pre></div>
 | |
| 
 | |
| <p>Be careful when using the ".save" command as it will overwrite any
 | |
| preexisting database files having the same name without prompting for
 | |
| confirmation.  As with the ".open" command, you might want to use a
 | |
| full pathname with forward-slash directory separators to avoid ambiguity.
 | |
| 
 | |
| <a name="dotcmd"></a>
 | |
| 
 | |
| </p><h1 id="special_commands_to_sqlite3_dot_commands_"><span>3. </span>Special commands to sqlite3 (dot-commands)</h1>
 | |
| 
 | |
| <p>
 | |
| Most of the time, sqlite3 just reads lines of input and passes them
 | |
| on to the SQLite library for execution.
 | |
| But input lines that begin with a dot (".")
 | |
| are intercepted and interpreted by the sqlite3 program itself.
 | |
| These "dot commands" are typically used to change the output format
 | |
| of queries, or to execute certain prepackaged query statements.
 | |
| There were originally just a few dot commands, but over the years
 | |
| many new features have accumulated so that today there over 60.
 | |
| </p>
 | |
| 
 | |
| <p>
 | |
| For a listing of the available dot commands, you can enter ".help" with
 | |
| no arguments.  Or enter ".help TOPIC" for detailed information about TOPIC.
 | |
| The list of available dot-commands follows:
 | |
| </p>
 | |
| 
 | |
| <div class="codeblock"><pre>sqlite> <b>.help</b>
 | |
| .archive ...             Manage SQL archives
 | |
| .auth ON|OFF             Show authorizer callbacks
 | |
| .backup ?DB? FILE        Backup DB (default "main") to FILE
 | |
| .bail on|off             Stop after hitting an error.  Default OFF
 | |
| .binary on|off           Turn binary output on or off.  Default OFF
 | |
| .cd DIRECTORY            Change the working directory to DIRECTORY
 | |
| .changes on|off          Show number of rows changed by SQL
 | |
| .check GLOB              Fail if output since .testcase does not match
 | |
| .clone NEWDB             Clone data into NEWDB from the existing database
 | |
| .databases               List names and files of attached databases
 | |
| .dbconfig ?op? ?val?     List or change sqlite3_db_config() options
 | |
| .dbinfo ?DB?             Show status information about the database
 | |
| .dump ?TABLE?            Render database content as SQL
 | |
| .echo on|off             Turn command echo on or off
 | |
| .eqp on|off|full|...     Enable or disable automatic EXPLAIN QUERY PLAN
 | |
| .excel                   Display the output of next command in spreadsheet
 | |
| .exit ?CODE?             Exit this program with return-code CODE
 | |
| .expert                  EXPERIMENTAL. Suggest indexes for queries
 | |
| .explain ?on|off|auto?   Change the EXPLAIN formatting mode.  Default: auto
 | |
| .filectrl CMD ...        Run various sqlite3_file_control() operations
 | |
| .fullschema ?--indent?   Show schema and the content of sqlite_stat tables
 | |
| .headers on|off          Turn display of headers on or off
 | |
| .help ?-all? ?PATTERN?   Show help text for PATTERN
 | |
| .import FILE TABLE       Import data from FILE into TABLE
 | |
| .imposter INDEX TABLE    Create imposter table TABLE on index INDEX
 | |
| .indexes ?TABLE?         Show names of indexes
 | |
| .limit ?LIMIT? ?VAL?     Display or change the value of an SQLITE_LIMIT
 | |
| .lint OPTIONS            Report potential schema issues.
 | |
| .load FILE ?ENTRY?       Load an extension library
 | |
| .log FILE|off            Turn logging on or off.  FILE can be stderr/stdout
 | |
| .mode MODE ?TABLE?       Set output mode
 | |
| .nullvalue STRING        Use STRING in place of NULL values
 | |
| .once ?OPTIONS? ?FILE?   Output for the next SQL command only to FILE
 | |
| .open ?OPTIONS? ?FILE?   Close existing database and reopen FILE
 | |
| .output ?FILE?           Send output to FILE or stdout if FILE is omitted
 | |
| .parameter CMD ...       Manage SQL parameter bindings
 | |
| .print STRING...         Print literal STRING
 | |
| .progress N              Invoke progress handler after every N opcodes
 | |
| .prompt MAIN CONTINUE    Replace the standard prompts
 | |
| .quit                    Exit this program
 | |
| .read FILE               Read input from FILE
 | |
| .recover                 Recover as much data as possible from corrupt db.
 | |
| .restore ?DB? FILE       Restore content of DB (default "main") from FILE
 | |
| .save FILE               Write in-memory database into FILE
 | |
| .scanstats on|off        Turn sqlite3_stmt_scanstatus() metrics on or off
 | |
| .schema ?PATTERN?        Show the CREATE statements matching PATTERN
 | |
| .selftest ?OPTIONS?      Run tests defined in the SELFTEST table
 | |
| .separator COL ?ROW?     Change the column and row separators
 | |
| .sha3sum ...             Compute a SHA3 hash of database content
 | |
| .shell CMD ARGS...       Run CMD ARGS... in a system shell
 | |
| .show                    Show the current values for various settings
 | |
| .stats ?on|off?          Show stats or turn stats on or off
 | |
| .system CMD ARGS...      Run CMD ARGS... in a system shell
 | |
| .tables ?TABLE?          List names of tables matching LIKE pattern TABLE
 | |
| .testcase NAME           Begin redirecting output to 'testcase-out.txt'
 | |
| .testctrl CMD ...        Run various sqlite3_test_control() operations
 | |
| .timeout MS              Try opening locked tables for MS milliseconds
 | |
| .timer on|off            Turn SQL timer on or off
 | |
| .trace ?OPTIONS?         Output each SQL statement as it is run
 | |
| .vfsinfo ?AUX?           Information about the top-level VFS
 | |
| .vfslist                 List all available VFSes
 | |
| .vfsname ?AUX?           Print the name of the VFS stack
 | |
| .width NUM1 NUM2 ...     Set minimum column widths for columnar output
 | |
| sqlite>
 | |
| </pre></div>
 | |
| 
 | |
| <a name="dotrules"></a>
 | |
| 
 | |
| <h1 id="rules_for_dot_commands_"><span>4. </span>Rules for "dot-commands"</h1>
 | |
| 
 | |
| <p>Ordinary SQL statements are free-form, and can be
 | |
| spread across multiple lines, and can have whitespace and
 | |
| comments anywhere.  Dot-commands are
 | |
| more restrictive:
 | |
| 
 | |
| </p><ul>
 | |
| <li>A dot-command must begin with the "." at the left margin
 | |
|     with no preceding whitespace.
 | |
| </li><li>The dot-command must be entirely contained on a single input line.
 | |
| </li><li>A dot-command cannot occur in the middle of an ordinary SQL
 | |
|     statement.  In other words, a dot-command cannot occur at a
 | |
|     continuation prompt.
 | |
| </li><li>Dot-commands do not recognize comments.
 | |
| </li></ul>
 | |
| 
 | |
| <p>The dot-commands
 | |
| are interpreted by the sqlite3.exe command-line program, not by
 | |
| SQLite itself.  So none of the dot-commands will work as an argument
 | |
| to SQLite interfaces like <a href="c3ref/prepare.html">sqlite3_prepare()</a> or <a href="c3ref/exec.html">sqlite3_exec()</a>.
 | |
| 
 | |
| <a name="dotmode"></a>
 | |
| 
 | |
| </p><h1 id="changing_output_formats"><span>5. </span>Changing Output Formats</h1>
 | |
| 
 | |
| <p>The sqlite3 program is able to show the results of a query
 | |
| in 14 different formats:
 | |
| </p><div class="columns" style="columns:8em auto;">
 | |
| <ul style="padding-top:0;padding-left:4em;">
 | |
| <li> ascii
 | |
| </li><li> box
 | |
| </li><li> csv
 | |
| </li><li> column
 | |
| </li><li> html
 | |
| </li><li> insert
 | |
| </li><li> json
 | |
| </li><li> line
 | |
| </li><li> list
 | |
| </li><li> markdown
 | |
| </li><li> quote
 | |
| </li><li> table
 | |
| </li><li> tabs
 | |
| </li><li> tcl
 | |
| </li></ul></div>
 | |
| 
 | |
| <p>You can use the ".mode" dot command to switch between these output
 | |
| formats.
 | |
| >The default output mode is "list".  In
 | |
| list mode, each row of a query result is written on one line of
 | |
| output and each column within that row is separated by a specific
 | |
| separator string.  The default separator is a pipe symbol ("|").
 | |
| List mode is especially useful when you are going to send the output
 | |
| of a query to another program (such as AWK) for additional processing.</p>
 | |
| 
 | |
| <div class="codeblock"><pre>sqlite> <b>.mode list</b>
 | |
| sqlite> <b>select * from tbl1;</b>
 | |
| hello|10
 | |
| goodbye|20
 | |
| sqlite>
 | |
| </pre></div>
 | |
| 
 | |
| <p>Use the ".separator" dot command to change the separator.
 | |
| For example, to change the separator to a comma and
 | |
| a space, you could do this:</p>
 | |
| 
 | |
| <div class="codeblock"><pre>sqlite> <b>.separator ", "</b>
 | |
| sqlite> <b>select * from tbl1;</b>
 | |
| hello, 10
 | |
| goodbye, 20
 | |
| sqlite>
 | |
| </pre></div>
 | |
| 
 | |
| <p>The next ".mode" command will reset the ".separator" back to its default.
 | |
| So you will need repeat the ".separator" command whenever you change
 | |
| modes if you want to continue using a non-standard separator.
 | |
| 
 | |
| <a name="dotmodequote"></a>
 | |
| 
 | |
| </p><p>In "quote" mode, the output is formatted as SQL literals.  Strings are
 | |
| enclosed in single-quotes and internal single-quotes are escaped by doubling.
 | |
| Blobs are displayed in hexadecimal blob literal notation (Ex: x'abcd').
 | |
| Numbers are displayed as ASCII text and NULL values are shown as "NULL".
 | |
| All columns are separated from each other by a comma (or whatever alternative
 | |
| character is selected using ".separator").
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> <b>.mode quote</b>
 | |
| sqlite> <b>select * from tbl1;</b>
 | |
| 'hello',10
 | |
| 'goodbye',20
 | |
| sqlite>
 | |
| </pre></div>
 | |
| 
 | |
| <p>In "line" mode, each column in a row of the database
 | |
| is shown on a line by itself.  Each line consists of the column
 | |
| name, an equal sign and the column data.  Successive records are
 | |
| separated by a blank line.  Here is an example of line mode
 | |
| output:</p>
 | |
| 
 | |
| <div class="codeblock"><pre>sqlite> <b>.mode line</b>
 | |
| sqlite> <b>select * from tbl1;</b>
 | |
| one = hello
 | |
| two = 10
 | |
| 
 | |
| one = goodbye
 | |
| two = 20
 | |
| sqlite>
 | |
| </pre></div>
 | |
| 
 | |
| <p>In column mode, each record is shown on a separate line with the
 | |
| data aligned in columns.  For example:</p>
 | |
| 
 | |
| <div class="codeblock"><pre>sqlite> <b>.mode column</b>
 | |
| sqlite> <b>select * from tbl1;</b>
 | |
| one       two       
 | |
| --------  ---
 | |
| hello     10        
 | |
| goodbye   20        
 | |
| sqlite>
 | |
| </pre></div>
 | |
| 
 | |
| <p>In "column" mode (and also in "box", "table", and "markdown" modes)
 | |
| the width of columns adjusts automatically.  But you can override this,
 | |
| providing a minimum width for each column using the ".width" command.
 | |
| The arguments to ".width" are integers which are the minimum number of
 | |
| spaces to devote to each column.  Negative numbers mean right-justify.
 | |
| Thus:</p>
 | |
| 
 | |
| <div class="codeblock"><pre>sqlite> <b>.width 12 -6</b>
 | |
| sqlite> <b>select * from tbl1;</b>
 | |
| one              two
 | |
| ------------  ------
 | |
| hello!            10
 | |
| goodbye           20
 | |
| sqlite>
 | |
| </pre></div>
 | |
| 
 | |
| <p>A width of 0 means the column width is chosen automatically.
 | |
| Unspecified columns widths to go zero.  Hence, the command
 | |
| ".width" with no arguments sets all columns widths to zero and
 | |
| hence causes all column widths to be determine automatically.
 | |
| 
 | |
| </p><p>The "column" mode is a tabular output format.  Other
 | |
| tabular output formats as "box", "markdown", and "table":
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> <b>.width</b>
 | |
| sqlite> <b>.mode markdown</b>
 | |
| sqlite> <b>select * from tbl1;</b>
 | |
| |   one   | two |
 | |
| |---------|-----|
 | |
| | hello!  | 10  |
 | |
| | goodbye | 20  |
 | |
| sqlite> <b>.mode table</b>
 | |
| sqlite> <b>select * from tbl1;</b>
 | |
| +---------+-----+
 | |
| |   one   | two |
 | |
| +---------+-----+
 | |
| | hello!  | 10  |
 | |
| | goodbye | 20  |
 | |
| +---------+-----+
 | |
| sqlite> <b>.mode box</b>
 | |
| sqlite> <b>select * from tbl1;</b>
 | |
| ┌─────────┬─────┐
 | |
| │   one   │ two │
 | |
| ├─────────┼─────┤
 | |
| │ hello!  │ 10  │
 | |
| │ goodbye │ 20  │
 | |
| └─────────┴─────┘
 | |
| sqlite>
 | |
| </pre></div>
 | |
| 
 | |
| <p>Another useful output mode is "insert".  In insert mode, the output
 | |
| is formatted to look like SQL INSERT statements.  Use insert
 | |
| mode to generate text that can later be used to input data into a 
 | |
| different database.</p>
 | |
| 
 | |
| <p>When specifying insert mode, you have to give an extra argument
 | |
| which is the name of the table to be inserted into.  For example:</p>
 | |
| 
 | |
| <div class="codeblock"><pre>sqlite> <b>.mode insert new_table</b>
 | |
| sqlite> <b>select * from tbl1;</b>
 | |
| INSERT INTO "new_table" VALUES('hello',10);
 | |
| INSERT INTO "new_table" VALUES('goodbye',20);
 | |
| sqlite>
 | |
| </pre></div>
 | |
| 
 | |
| 
 | |
| <p>Other output modes include "html", "json", and "tcl".  Try these
 | |
| yourself to see what they do.
 | |
| </p>
 | |
| 
 | |
| <a name="dotoutput"></a>
 | |
| 
 | |
| <h1 id="writing_results_to_a_file"><span>6. </span>Writing results to a file</h1>
 | |
| 
 | |
| <p>By default, sqlite3 sends query results to standard output.  You
 | |
| can change this using the ".output" and ".once" commands.  Just put 
 | |
| the name of an output file as an argument to .output and all subsequent
 | |
| query results will be written to that file.  Or use the .once command
 | |
| instead of .output and output will only be redirected for the single next
 | |
| command before reverting to the console.  Use .output with no arguments to
 | |
| begin writing to standard output again.  For example:</p>
 | |
| 
 | |
| <div class="codeblock"><pre>sqlite> <b>.mode list</b>
 | |
| sqlite> <b>.separator |</b>
 | |
| sqlite> <b>.output test_file_1.txt</b>
 | |
| sqlite> <b>select * from tbl1;</b>
 | |
| sqlite> <b>.exit</b>
 | |
| $ <b>cat test_file_1.txt</b>
 | |
| hello|10
 | |
| goodbye|20
 | |
| $
 | |
| </pre></div>
 | |
| 
 | |
| <p>If the first character of the ".output" or ".once" filename is a pipe
 | |
| symbol ("|") then the remaining characters are treated as a command and the
 | |
| output is sent to that command.  This makes it easy to pipe the results
 | |
| of a query into some other process.  For example, the 
 | |
| "open -f" command on a Mac opens a text editor to display the content that
 | |
| it reads from standard input.  So to see the results of a query
 | |
| in a text editor, one could type:</p>
 | |
| 
 | |
| <div class="codeblock"><pre>sqlite3> <b>.once '|open -f'</b>
 | |
| sqlite3> <b>SELECT * FROM bigTable;</b>
 | |
| </pre></div>
 | |
| 
 | |
| <p>If the ".output" or ".once" commands have an argument of "-e" then
 | |
| output is collected into a temporary file and the system text editor is
 | |
| invoked on that text file.  Thus, the command ".once -e" achieves the
 | |
| same result as ".once '|open -f'" but with the benefit of being portable
 | |
| across all systems.
 | |
| 
 | |
| </p><p>If the ".output" or ".once" commands have a "-x" argument, that causes
 | |
| them to accumulate output as Comma-Separated-Values (CSV) in a temporary
 | |
| file, then invoke the default system utility for viewing CSV files
 | |
| (usually a spreadsheet program) on the result.  This is a quick way of
 | |
| sending the result of a query to a spreadsheet for easy viewing:
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite3> <b>.once -x</b>
 | |
| sqlite3> <b>SELECT * FROM bigTable;</b>
 | |
| </pre></div>
 | |
| 
 | |
| <a name="dotexcel"></a>
 | |
| 
 | |
| <p>The ".excel" command is an alias for ".once -x".  It does exactly the same
 | |
| thing.
 | |
| 
 | |
| <a name="fileio"></a>
 | |
| 
 | |
| </p><h2 id="file_i_o_functions"><span>6.1. </span>File I/O Functions</h2>
 | |
| 
 | |
| <p>The command-line shell adds two <a href="appfunc.html">application-defined SQL functions</a> that
 | |
| facilitate reading content from a file into a table column, and writing the
 | |
| content of a column into a file, respectively.
 | |
| 
 | |
| </p><p>The readfile(X) SQL function reads the entire content of the file named
 | |
| X and returns that content as a BLOB.  This can be used to load content into
 | |
| a table.  For example:
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> <b>CREATE TABLE images(name TEXT, type TEXT, img BLOB);</b>
 | |
| sqlite> <b>INSERT INTO images(name,type,img</b>)
 | |
|    ...> <b>  VALUES('icon','jpeg',readfile('icon.jpg'));</b>
 | |
| </pre></div>
 | |
| 
 | |
| <p>The writefile(X,Y) SQL function write the blob Y into the file named X
 | |
| and returns the number of bytes written.  Use this function to extract
 | |
| the content of a single table column into a file.  For example:
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> <b>SELECT writefile('icon.jpg',img) FROM images WHERE name='icon';</b>
 | |
| </pre></div>
 | |
| 
 | |
| <p>Note that the readfile(X) and writefile(X,Y) functions are extension
 | |
| functions and are not built into the core SQLite library.  These routines
 | |
| are available as a <a href="loadext.html">loadable extension</a> in the
 | |
| <a href="http://www.sqlite.org/src/artifact?ci=trunk&filename=ext/misc/fileio.c">ext/misc/fileio.c</a>
 | |
| source file in the <a href="download.html#srctree">SQLite source code repositories</a>.
 | |
| 
 | |
| <a name="editfunc"></a>
 | |
| 
 | |
| </p><h2 id="the_edit_sql_function"><span>6.2. </span>The edit() SQL function</h2>
 | |
| 
 | |
| <p>The CLI has another build-in SQL function named edit().  Edit() takes
 | |
| one or two arguments.  The first argument is a value - usually a large
 | |
| multi-line string to be edited.  The second argument is the name of a
 | |
| text editor.  If the second argument is omitted, the VISUAL environment
 | |
| variable is used.  The edit() function writes its first argument into a
 | |
| temporary file, invokes the editor on the temporary file, rereads the file
 | |
| back into memory after the editor is done, then returns the edited text.
 | |
| 
 | |
| </p><p>The edit() function can be used to make changes to large text
 | |
| values.  For example:
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> <b>UPDATE docs SET body=edit(body) WHERE name='report-15';</b>
 | |
| </pre></div>
 | |
| 
 | |
| <p>In this example, the content of the docs.body field for the entry where
 | |
| docs.name is "report-15" will be sent to the editor.  After the editor returns,
 | |
| the result will be written back into the docs.body field.
 | |
| 
 | |
| </p><p>The default operation of edit() is to invoke a text editor.  But by using
 | |
| an alternative edit program in the second argument, you can also get it to edit
 | |
| images or other non-text resources.  For example, if you want to modify a JPEG
 | |
| image that happens to be stored in a field of a table, you could run:
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> <b>UPDATE pics SET img=edit(img,'gimp') WHERE id='pic-1542';</b>
 | |
| </pre></div>
 | |
| 
 | |
| <p>The edit program can also be used as a viewer, by simply ignoring the
 | |
| return value.  For example, to merely look at the image above, you might run:
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> <b>SELECT length(edit(img,'gimp')) WHERE id='pic-1542';</b>
 | |
| </pre></div>
 | |
| 
 | |
| 
 | |
| <a name="schema"></a>
 | |
| 
 | |
| <h1 id="querying_the_database_schema"><span>7. </span>Querying the database schema</h1>
 | |
| 
 | |
| <p>The sqlite3 program provides several convenience commands that
 | |
| are useful for looking at the schema of the database.  There is
 | |
| nothing that these commands do that cannot be done by some other
 | |
| means.  These commands are provided purely as a shortcut.</p>
 | |
| 
 | |
| <a name="dtables"></a>
 | |
| 
 | |
| <p>For example, to see a list of the tables in the database, you
 | |
| can enter ".tables".</p>
 | |
| 
 | |
| 
 | |
| <div class="codeblock"><pre>sqlite> <b>.tables</b>
 | |
| tbl1
 | |
| tbl2
 | |
| sqlite>
 | |
| </pre></div>
 | |
| 
 | |
| 
 | |
| <p>The ".tables" command is similar to setting list mode then
 | |
| executing the following query:</p>
 | |
| 
 | |
| <div class="codeblock"><pre>SELECT name FROM sqlite_schema 
 | |
| WHERE type IN ('table','view') AND name NOT LIKE 'sqlite_%'
 | |
| ORDER BY 1
 | |
| </pre></div>
 | |
| 
 | |
| <p>But the ".tables" command does more.  It queries the <a href="schematab.html">sqlite_schema</a> table
 | |
| for all <a href="lang_attach.html">attached</a> databases, not just the primary database.  And it arranges
 | |
| its output into neat columns.
 | |
| 
 | |
| </p><p>The ".indexes" command works in a similar way to list all of
 | |
| the indexes. If the ".indexes" command is given an argument which is
 | |
| the name of a table, then it shows just indexes on that table.
 | |
| 
 | |
| <a name="dschema"></a>
 | |
| 
 | |
| </p><p>The ".schema" command shows the complete schema for the database,
 | |
| or for a single table if an optional tablename argument is provided:
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> <b>.schema</b>
 | |
| create table tbl1(one varchar(10), two smallint)
 | |
| CREATE TABLE tbl2 (
 | |
|   f1 varchar(30) primary key,
 | |
|   f2 text,
 | |
|   f3 real
 | |
| )
 | |
| sqlite> <b>.schema tbl2</b>
 | |
| CREATE TABLE tbl2 (
 | |
|   f1 varchar(30) primary key,
 | |
|   f2 text,
 | |
|   f3 real
 | |
| )
 | |
| sqlite>
 | |
| </pre></div>
 | |
| 
 | |
| 
 | |
| <p>The ".schema" command is roughly the same as setting
 | |
| list mode, then entering the following query:</p>
 | |
| 
 | |
| <div class="codeblock"><pre>SELECT sql FROM sqlite_schema
 | |
| ORDER BY tbl_name, type DESC, name
 | |
| </pre></div>
 | |
| 
 | |
| <p>As with ".tables", the ".schema" command shows the schema for
 | |
| all <a href="lang_attach.html">attached</a> databases.  If you only want to see the schema for
 | |
| a single database (perhaps "main") then you can add an argument
 | |
| to ".schema" to restrict its output:
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> <b>.schema main.*</b>
 | |
| </pre></div>
 | |
| 
 | |
| <p>The ".schema" command can be augmented with the "--indent" option,
 | |
| in which case it tries to reformat the various CREATE statements of
 | |
| the schema so that they are more easily readable by humans.
 | |
| 
 | |
| </p><p>The ".databases" command shows a list of all databases open in
 | |
| the current connection.  There will always be at least 2.  The first
 | |
| one is "main", the original database opened.  The second is "temp",
 | |
| the database used for temporary tables. There may be additional 
 | |
| databases listed for databases attached using the ATTACH statement.
 | |
| The first output column is the name the database is attached with, 
 | |
| and the second column is the filename of the external file.</p>
 | |
| 
 | |
| <div class="codeblock"><pre>sqlite> <b>.databases</b>
 | |
| </pre></div>
 | |
| 
 | |
| <a name="fullschema"></a>
 | |
| 
 | |
| <p>The ".fullschema" dot-command works like the ".schema" command in
 | |
| that it displays the entire database schema.  But ".fullschema" also
 | |
| includes dumps of the statistics tables "sqlite_stat1", "sqlite_stat3",
 | |
| and "sqlite_stat4", if they exist.  The ".fullschema" command normally
 | |
| provides all of the information needed to exactly recreate a query
 | |
| plan for a specific query.  When reporting suspected problems with
 | |
| the SQLite query planner to the SQLite development team, developers
 | |
| are requested to provide the complete ".fullschema" output as part
 | |
| of the trouble report.  Note that the sqlite_stat3 and sqlite_stat4
 | |
| tables contain samples of index entries and so might contain sensitive
 | |
| data, so do not send the ".fullschema" output of a proprietary database
 | |
| over a public channel.</p>
 | |
| 
 | |
| <a name="csv"></a>
 | |
| 
 | |
| <h1 id="csv_import"><span>8. </span>CSV Import</h1>
 | |
| 
 | |
| <p>Use the ".import" command to import CSV (comma separated value) data into
 | |
| an SQLite table.  The ".import" command takes two arguments which are the
 | |
| name of the disk file from which CSV data is to be read and the name of the
 | |
| SQLite table into which the CSV data is to be inserted.
 | |
| 
 | |
| </p><p>Note that it is important to set the "mode" to "csv" before running the
 | |
|  ".import" command.  This is necessary to prevent the command-line shell
 | |
| from trying to interpret the input file text as some other format.
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> <b>.import C:/work/somedata.csv tab1</b>
 | |
| </pre></div>
 | |
| 
 | |
| <p>There are two cases to consider:  (1) Table "tab1" does not previously
 | |
| exist and (2) table "tab1" does already exist.
 | |
| 
 | |
| </p><p>In the first case, when the table does not previously exist, the table is
 | |
| automatically created and the content of the first row of the input CSV
 | |
| file is used to determine the name of all the columns in the table.  In
 | |
| other words, if the table does not previously exist, the first row of the
 | |
| CSV file is interpreted to be column names and the actual data starts on
 | |
| the second row of the CSV file.
 | |
| 
 | |
| </p><p>For the second case, when the table already exists, every row of the
 | |
| CSV file, including the first row, is assumed to be actual content.  If
 | |
| the CSV file contains an initial row of column labels, you can cause
 | |
| the .import command to skip that initial row using the "--skip 1" option.
 | |
| 
 | |
| 
 | |
| 
 | |
| <a name="csvout"></a>
 | |
| 
 | |
| </p><h1 id="csv_export"><span>9. </span>CSV Export</h1>
 | |
| 
 | |
| <p>To export an SQLite table (or part of a table) as CSV, simply set
 | |
| the "mode" to "csv" and then run a query to extract the desired rows
 | |
| of the table.
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> <b>.headers on</b>
 | |
| sqlite> <b>.mode csv</b>
 | |
| sqlite> <b>.once c:/work/dataout.csv</b>
 | |
| sqlite> <b>SELECT * FROM tab1;</b>
 | |
| sqlite> <b>.system c:/work/dataout.csv</b>
 | |
| </pre></div>
 | |
| 
 | |
| <p>In the example above, the ".headers on" line causes column labels to
 | |
| be printed as the first row of output.  This means that the first row of
 | |
| the resulting CSV file will contain column labels.  If column labels are
 | |
| not desired, set ".headers off" instead. (The ".headers off" setting is
 | |
| the default and can be omitted if the headers have not been previously
 | |
| turned on.)
 | |
| 
 | |
| </p><p>The line ".once <i>FILENAME</i>" causes all query output to go into
 | |
| the named file instead of being printed on the console.  In the example
 | |
| above, that line causes the CSV content to be written into a file named
 | |
| "C:/work/dataout.csv".
 | |
| 
 | |
| </p><p>The final line of the example (the ".system c:/work/dataout.csv")
 | |
| has the same effect as double-clicking on the c:/work/dataout.csv file
 | |
| in windows.  This will typically bring up a spreadsheet program to display
 | |
| the CSV file.
 | |
| 
 | |
| </p><p>That command only works as written on Windows.  
 | |
| The equivalent line on a Mac would be:
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> <b>.system open dataout.csv</b>
 | |
| </pre></div>
 | |
| 
 | |
| <p>On Linux and other unix systems you will need to enter something like:
 | |
| 
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> <b>.system xdg-open dataout.csv</b>
 | |
| </pre></div>
 | |
| 
 | |
| <a name="exexcel*"></a>
 | |
| 
 | |
| <h2 id="_export_to_excel_"><span>9.1. </span> Export to Excel </h2>
 | |
| 
 | |
| <p>To simplify export to a spreadsheet, the CLI provides the
 | |
| ".excel" command which captures the output of a single query and sends
 | |
| that output to the default spreadsheet program on the host computer.
 | |
| Use it like this:
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> <b>.excel</b>
 | |
| sqlite> <b>SELECT * FROM tab;</b>
 | |
| </pre></div>
 | |
| 
 | |
| <p>
 | |
| The command above writes the output of the query as CSV into a temporary
 | |
| file, invokes the default handler for CSV files (usually the preferred
 | |
| spreadsheet program such as Excel or LibreOffice), then deletes the
 | |
| temporary file.  This is essentially a short-hand method of doing
 | |
| the sequence of ".csv", ".once", and ".system" commands described above.
 | |
| 
 | |
| </p><p>
 | |
| The ".excel" command is really an alias for ".once -x".  The -x option
 | |
| to .once causes it to writes results as CSV into a temporary file that
 | |
| is named with a ".csv" suffix, then invoke the systems default handler
 | |
| for CSV files.
 | |
| 
 | |
| </p><p>
 | |
| There is also a ".once -e" command which works similarly, except that
 | |
| it names the temporary file with a ".txt" suffix so that the default
 | |
| text editor for the system will be invoked, instead of the default
 | |
| spreadsheet.
 | |
| 
 | |
| <a name="zipdb"></a>
 | |
| 
 | |
| </p><h1 id="accessing_zip_archives_as_database_files"><span>10. </span>Accessing ZIP Archives As Database Files</h1>
 | |
| 
 | |
| <p>In addition to reading and writing SQLite database files,
 | |
| the <b>sqlite3</b> program will also read and write ZIP archives.
 | |
| Simply specify a ZIP archive filename in place of an SQLite database
 | |
| filename on the initial command line, or in the ".open" command,
 | |
| and <b>sqlite3</b> will automatically detect that the file is a
 | |
| ZIP archive instead of an SQLite database and will open it as such.
 | |
| This works regardless of file suffix.  So you can open JAR, DOCX,
 | |
| and ODP files and any other file format that is really a ZIP
 | |
| archive and SQLite will read it for you.
 | |
| 
 | |
| </p><p>A ZIP archive appears to be a database containing a single table
 | |
| with the following schema:
 | |
| 
 | |
| </p><div class="codeblock"><pre>CREATE TABLE zip(
 | |
|   name,     // Name of the file
 | |
|   mode,     // Unix-style file permissions
 | |
|   mtime,    // Timestamp, seconds since 1970
 | |
|   sz,       // File size after decompression
 | |
|   rawdata,  // Raw compressed file data
 | |
|   data,     // Uncompressed file content
 | |
|   method    // ZIP compression method code
 | |
| );
 | |
| </pre></div>
 | |
| 
 | |
| <p>So, for example, if you wanted to see the compression efficiency
 | |
| (expressed as the size of the compressed content relative to the
 | |
| original uncompressed file size) for all files in the ZIP archive,
 | |
| sorted from most compressed to least compressed, you could run a
 | |
| query like this:
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> SELECT name, (100.0*length(rawdata))/sz FROM zip ORDER BY 2;
 | |
| </pre></div>
 | |
| 
 | |
| <p>Or using <a href="cli.html#fileio">file I/O functions</a>, you can extract elements of the
 | |
| ZIP archive:
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> SELECT writefile(name,content) FROM zip
 | |
|    ...> WHERE name LIKE 'docProps/%';
 | |
| </pre></div>
 | |
| 
 | |
| <h2 id="how_zip_archive_access_is_implemented"><span>10.1. </span>How ZIP archive access is implemented</h2>
 | |
| 
 | |
| <p>The command-line shell uses the <a href="zipfile.html">Zipfile virtual table</a> to
 | |
| access ZIP archives.  You can see this by running the ".schema"
 | |
| command when a ZIP archive is open:
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> .schema
 | |
| CREATE VIRTUAL TABLE zip USING zipfile('document.docx')
 | |
| /* zip(name,mode,mtime,sz,rawdata,data,method) */;
 | |
| </pre></div>
 | |
| 
 | |
| <p>When opening a file, if the command-line client discovers that the
 | |
| file is ZIP archive instead of an SQLite database, it actually opens
 | |
| an <a href="inmemorydb.html">in-memory database</a> and then in that in-memory database it creates
 | |
| an instance of the <a href="zipfile.html">Zipfile virtual table</a> that is attached to the
 | |
| ZIP archive.
 | |
| 
 | |
| </p><p>The special processing for opening ZIP archives is a trick of the
 | |
| command-line shell, not the core SQLite library.  So if you want to
 | |
| open a ZIP archive as a database in your application, you will need to
 | |
| activate the <a href="zipfile.html">Zipfile virtual table</a> module then run an appropriate
 | |
| <a href="lang_createvtab.html">CREATE VIRTUAL TABLE</a> statement.
 | |
| 
 | |
| 
 | |
| <a name="dump"></a>
 | |
| 
 | |
| </p><h1 id="converting_an_entire_database_to_an_ascii_text_file"><span>11. </span>Converting An Entire Database To An ASCII Text File</h1>
 | |
| 
 | |
| <p>Use the ".dump" command to convert the entire contents of a
 | |
| database into a single ASCII text file.  This file can be converted
 | |
| back into a database by piping it back into <b>sqlite3</b>.</p>
 | |
| 
 | |
| <p>A good way to make an archival copy of a database is this:</p>
 | |
| 
 | |
| 
 | |
| <div class="codeblock"><pre>$ <b>sqlite3 ex1 .dump | gzip -c >ex1.dump.gz</b>
 | |
| </pre></div>
 | |
| 
 | |
| 
 | |
| <p>This generates a file named <b>ex1.dump.gz</b> that contains everything
 | |
| you need to reconstruct the database at a later time, or on another
 | |
| machine.  To reconstruct the database, just type:</p>
 | |
| 
 | |
| 
 | |
| <div class="codeblock"><pre>$ <b>zcat ex1.dump.gz | sqlite3 ex2</b>
 | |
| </pre></div>
 | |
| 
 | |
| 
 | |
| <p>The text format is pure SQL so you
 | |
| can also use the .dump command to export an SQLite database
 | |
| into other popular SQL database engines.  Like this:</p>
 | |
| 
 | |
| 
 | |
| <div class="codeblock"><pre>$ <b>createdb ex2</b>
 | |
| $ <b>sqlite3 ex1 .dump | psql ex2</b>
 | |
| </pre></div>
 | |
| 
 | |
| <a name="recover"></a>
 | |
| 
 | |
| <h1 id="recover_data_from_a_corrupted_database"><span>12. </span>Recover Data From a Corrupted Database</h1>
 | |
| 
 | |
| <p>Like the ".dump" command, ".recover" attempts to convert the entire 
 | |
| contents of a database file to text. The difference is that instead of
 | |
| reading data using the normal SQL database interface, ".recover"
 | |
| attempts to reassemble the database based on data extracted directly from 
 | |
| as many database pages as possible. If the database is corrupt, ".recover"
 | |
| is usually able to recover data from all uncorrupted parts of the database,
 | |
| whereas ".dump" stops when the first sign of corruption is encountered.
 | |
| 
 | |
| </p><p>If the ".recover" command recovers one or more rows that it cannot 
 | |
| attribute to any database table, the output script creates a "lost_and_found"
 | |
| table to store the orphaned rows. The schema of the lost_and_found
 | |
| table is as follows:
 | |
| 
 | |
| </p><div class="codeblock"><pre>CREATE TABLE lost_and_found(
 | |
|     rootpgno INTEGER,             -- root page of tree pgno is a part of
 | |
|     pgno INTEGER,                 -- page number row was found on
 | |
|     nfield INTEGER,               -- number of fields in row
 | |
|     id INTEGER,                   -- value of rowid field, or NULL
 | |
|     c0, c1, c2, c3...             -- columns for fields of row
 | |
| );
 | |
| </pre></div>
 | |
| 
 | |
| <p>The "lost_and_found" table contains one row for each orphaned row recovered
 | |
| from the database. Additionally, there is one row for each recovered index
 | |
| entry that cannot be attributed to any SQL index. This is because, in an
 | |
| SQLite database, the same format is used to store SQL index entries and
 | |
| WITHOUT ROWID table entries.
 | |
| 
 | |
| </p><table striped="1" style="margin:1em auto; width:80%; border-spacing:0">
 | |
|   <tr style="text-align:left"><th style="width:15ex">Column</th><th>Contents
 | |
|   </th></tr><tr style="text-align:left;background-color:#DDDDDD"><td>rootpgno</td><td> Even though it may not be possible to attribute the 
 | |
|       row to a specific database table, it may be part of a tree structure
 | |
|       within the database file. In this case, the root page number of that
 | |
|       tree structure is stored in this column. Or, if the page the row was
 | |
|       found on is not part of a tree structure, this column stores a copy of
 | |
|       the value in column "pgno" - the page number of the page the row was
 | |
|       found on. In many, although not all, cases, all rows in the
 | |
|       lost_and_found table with the same value in this column belong to the
 | |
|       same table.
 | |
| 
 | |
|   </td></tr><tr style="text-align:left"><td>pgno</td><td> The page number of the page on which this row was found.
 | |
| 
 | |
|   </td></tr><tr style="text-align:left;background-color:#DDDDDD"><td>nfield</td><td> The number of fields in this row.
 | |
| 
 | |
|   </td></tr><tr style="text-align:left"><td>id</td><td> If the row comes from a WITHOUT ROWID table, this column 
 | |
|       contains NULL. Otherwise, it contains the 64-bit integer rowid value for
 | |
|       the row.
 | |
| 
 | |
|   </td></tr><tr style="text-align:left;background-color:#DDDDDD"><td>c0, c1, c2...</td><td> The values for each column of the row
 | |
|       are stored in these columns. The ".recover" command creates the
 | |
|       lost_and_found table with as many columns as required by the longest
 | |
|       orphaned row.
 | |
| </td></tr></table>
 | |
| 
 | |
| <p>If the recovered database schema already contains a table named
 | |
| "lost_and_found", the ".recover" command uses the name "lost_and_found0". If
 | |
| the name "lost_and_found0" is also already taken, "lost_and_found1", and so
 | |
| on. The default name "lost_and_found" may be overridden by invoking ".recover"
 | |
| with the --lost-and-found switch. For example, to have the output script call
 | |
| the table "orphaned_rows":
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> .recover --lost-and-found orphaned_rows
 | |
| </pre></div>
 | |
| 
 | |
| <a name="dotload"></a>
 | |
| 
 | |
| <h1 id="loading_extensions"><span>13. </span>Loading Extensions</h1>
 | |
| 
 | |
| <p>You can add new custom <a href="appfunc.html">application-defined SQL functions</a>,
 | |
| <a href="datatype3.html#collation">collating sequences</a>, <a href="vtab.html">virtual tables</a>, and <a href="vfs.html">VFSes</a> to the command-line
 | |
| shell at run-time using the ".load" command.  First, convert the
 | |
| extension in to a DLL or shared library (as described in the
 | |
| <a href="loadext.html">Run-Time Loadable Extensions</a> document) then type:
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> .load /path/to/my_extension
 | |
| </pre></div>
 | |
| 
 | |
| <p>Note that SQLite automatically adds the appropriate extension suffix
 | |
| (".dll" on windows, ".dylib" on Mac, ".so" on most other unixes) to the
 | |
| extension filename.  It is generally a good idea to specify the full
 | |
| pathname of the extension.
 | |
| 
 | |
| </p><p>SQLite computes the entry point for the extension based on the extension
 | |
| filename.  To override this choice, simply add the name of the extension
 | |
| as a second argument to the ".load" command.
 | |
| 
 | |
| </p><p>Source code for several useful extensions can be found in the
 | |
| <a href="http://www.sqlite.org/src/tree?name=ext/misc&ci=trunk">ext/misc</a>
 | |
| subdirectory of the SQLite source tree.  You can use these extensions
 | |
| as-is, or as a basis for creating your own custom extensions to address
 | |
| your own particular needs.
 | |
| 
 | |
| 
 | |
| <a name="sha3sum"></a>
 | |
| 
 | |
| </p><h1 id="cryptographic_hashes_of_database_content"><span>14. </span>Cryptographic Hashes Of Database Content</h1>
 | |
| 
 | |
| <p>The ".sha3sum" dot-command computes a
 | |
| <a href="https://en.wikipedia.org/wiki/SHA-3">SHA3</a> hash of the <em>content</em>
 | |
| of the database.  To be clear, the hash is computed over the database content,
 | |
| not its representation on disk.  This means, for example, that a <a href="lang_vacuum.html">VACUUM</a>
 | |
| or similar data-preserving transformation does not change the hash.
 | |
| 
 | |
| </p><p>The ".sha3sum" command supports options "--sha3-224", "--sha3-256", 
 | |
| "--sha3-384", and "--sha3-512" to define which variety of SHA3 to use
 | |
| for the hash.  The default is SHA3-256.
 | |
| 
 | |
| </p><p>The database schema (in the <a href="schematab.html">sqlite_schema</a> table) is not normally
 | |
| included in the hash, but can be added by the "--schema" option.
 | |
| 
 | |
| </p><p>The ".sha3sum" command takes a single optional argument which is a
 | |
| <a href="lang_expr.html#like">LIKE</a> pattern.  If this option is present, only tables whose names match
 | |
| the <a href="lang_expr.html#like">LIKE</a> pattern will be hashed.
 | |
| 
 | |
| </p><p>The ".sha3sum" command is implemented with the help of the
 | |
| <a href="https://www.sqlite.org/src/file/ext/misc/shathree.c">extension function "sha3_query()"</a>
 | |
| that is included with the command-line shell.
 | |
| 
 | |
| <a name="selftest"></a>
 | |
| 
 | |
| </p><h1 id="database_content_self_tests"><span>15. </span>Database Content Self-Tests</h1>
 | |
| 
 | |
| <p>The ".selftest" command attempts to verify that a database is
 | |
| intact and is not corrupt.  
 | |
| The .selftest command looks for a table in schema named "selftest"
 | |
| and defined as follows:
 | |
| 
 | |
| </p><div class="codeblock"><pre>CREATE TABLE selftest(
 | |
|   tno INTEGER PRIMARY KEY,  -- Test number
 | |
|   op TEXT,                  -- 'run' or 'memo'
 | |
|   cmd TEXT,                 -- SQL command to run, or text of "memo"
 | |
|   ans TEXT                  -- Expected result of the SQL command
 | |
| );
 | |
| </pre></div>
 | |
| 
 | |
| <p>The .selftest command reads the rows of the selftest table in
 | |
| selftest.tno order.
 | |
| For each 'memo' row, it writes the text in 'cmd' to the output.  For
 | |
| each 'run' row, it runs the 'cmd' text as SQL and compares the result
 | |
| to the value in 'ans', and shows an error message if the results differ.
 | |
| 
 | |
| </p><p>If there is no selftest table, the ".selftest" command runs
 | |
| <a href="pragma.html#pragma_integrity_check">PRAGMA integrity_check</a>.
 | |
| 
 | |
| </p><p>The ".selftest --init" command creates the selftest table if it
 | |
| does not already exists, then appends entries that check the SHA3
 | |
| hash of the content of all tables.  Subsequent runs of ".selftest"
 | |
| will verify that the database has not been changed in any way.  To
 | |
| generates tests to verify that a subset of the tables are unchanged,
 | |
| simply run ".selftest --init" then <a href="lang_delete.html">DELETE</a> the selftest rows that
 | |
| refer to tables that are not constant.  
 | |
| 
 | |
| <a name="sqlar"></a>
 | |
| 
 | |
| </p><h1 id="sqlite_archive_support"><span>16. </span>SQLite Archive Support</h1>
 | |
| 
 | |
| <p>The ".archive" dot-command and the "-A" command-line option
 | |
| provide built-in support for the 
 | |
| <a href="sqlar.html">SQLite Archive format</a>. The interface is similar to
 | |
| that of the "tar" command on unix systems. Each invocation of the ".ar"
 | |
| command must specify a single command option. The following commands
 | |
| are available for ".archive":
 | |
| 
 | |
| </p><table striped="1" style="margin:1em auto; width:80%; border-spacing:0">
 | |
|   <tr style="text-align:left"><th style="width:15ex">Option</th><th style="width:17ex">Long Option</th><th>Purpose
 | |
|   </th></tr><tr style="text-align:left;background-color:#DDDDDD"><td>-c</td><td>--create</td><td>Create a new archive containing specified files.
 | |
|   </td></tr><tr style="text-align:left"><td>-x</td><td>--extract</td><td>Extract specified files from archive.
 | |
|   </td></tr><tr style="text-align:left;background-color:#DDDDDD"><td>-i</td><td>--insert</td><td>Add files to existing archive.
 | |
|   </td></tr><tr style="text-align:left"><td>-t</td><td>--list</td><td>List the files in the archive.
 | |
|   </td></tr><tr style="text-align:left;background-color:#DDDDDD"><td>-u</td><td>--update</td><td>Add files to existing archive <em>if</em> they have changed.
 | |
| </td></tr></table>
 | |
| 
 | |
| <p>As well as the command option, each invocation of ".ar" may specify
 | |
| one or more modifier options. Some modifier options require an argument,
 | |
| some do not. The following modifier options are available:
 | |
| 
 | |
| </p><table striped="1" style="margin:1em auto; width:80%; border-spacing:0">
 | |
|   <tr style="text-align:left"><th style="width:15ex">Option</th><th style="width:17ex">Long Option</th><th>Purpose
 | |
|   </th></tr><tr style="text-align:left;background-color:#DDDDDD"><td>-v</td><td>--verbose</td><td>List each file as it is processed.
 | |
|   </td></tr><tr style="text-align:left"><td>-f FILE</td><td>--file FILE</td><td>If specified, use file FILE as the
 | |
|   archive. Otherwise, assume that the current "main" database is the 
 | |
|   archive to be operated on.
 | |
|   </td></tr><tr style="text-align:left;background-color:#DDDDDD"><td>-a FILE</td><td>--append FILE</td><td>Like --file, use file FILE as the
 | |
|   archive, but open the file using the 
 | |
|   <a href="https://sqlite.org/src/file/ext/misc/appendvfs.c">apndvfs VFS</a> so that
 | |
|   the archive will be appended to the end of FILE if FILE already exists.
 | |
|   </td></tr><tr style="text-align:left"><td>-C DIR</td><td>--directory DIR</td><td>If specified, interpret all relative
 | |
|   paths as relative to DIR, instead of the current working directory.
 | |
|   </td></tr><tr style="text-align:left;background-color:#DDDDDD"><td>-n</td><td>--dryrun</td><td>Show the SQL that would be run to carry out the
 | |
|                        archive operation, but do not actually change anything.
 | |
|   </td></tr><tr style="text-align:left"><td>--</td><td>--</td><td>All subsequent command line words are command arguments,
 | |
|   not options.
 | |
| </td></tr></table>
 | |
| 
 | |
| <p>
 | |
| For command-line usage, add the short style command-line options immediately
 | |
| following the "-A", without an intervening space.  All subsequent arguments
 | |
| are considered to be part of the .archive command.  For example, the following 
 | |
| commands are equivalent:
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite3 new_archive.db -Acv file1 file2 file3
 | |
| sqlite3 new_archive.db ".ar -cv file1 file2 file3"
 | |
| </pre></div>
 | |
| 
 | |
| <p>
 | |
| Long and short style options may be mixed. For example, the following are
 | |
| equivalent:
 | |
| 
 | |
| </p><div class="codeblock"><pre><i>-- Two ways to create a new archive named "new_archive.db" containing</i>
 | |
| <i>-- files "file1", "file2" and "file3".</i>
 | |
| .ar -c --file new_archive.db file1 file2 file3
 | |
| .ar -f new_archive.db --create file1 file2 file3
 | |
| </pre></div>
 | |
| 
 | |
| <p>Alternatively, the first argument following to ".ar" may be the concatenation
 | |
| of the short form of all required options (without the "-" characters). In 
 | |
| this case arguments for options requiring them are read from the command line
 | |
| next, and any remaining words are considered command arguments. For example:
 | |
| 
 | |
| </p><div class="codeblock"><pre><i>-- Create a new archive "new_archive.db" containing files "file1" and</i>
 | |
| <i>-- "file2" from directory "dir1".</i>
 | |
| .ar cCf dir1 new_archive.db file1 file2 file3
 | |
| </pre></div>
 | |
| 
 | |
| <h2 id="_sqlite_archive_create_command_"><span>16.1. </span> SQLite Archive Create Command </h2>
 | |
| 
 | |
| <p>Create a new archive, overwriting any existing archive (either in the current
 | |
| "main" db or in the file specified by a --file option). Each argument following
 | |
| the options is a file to add to the archive. Directories are imported
 | |
| recursively. See above for examples.
 | |
| 
 | |
| </p><h2 id="_sqlite_archive_extract_command_"><span>16.2. </span> SQLite Archive Extract Command </h2>
 | |
| 
 | |
| <p>Extract files from the archive (either to the current working directory or
 | |
| to the directory specified by a --directory option). If there are no arguments
 | |
| following the options all files are extracted from the archive. Or, if there
 | |
| are arguments, they are the names of files to extract from the archive. Any
 | |
| specified directories are extracted recursively. It is an error if any
 | |
| specified files are not part of the archive.
 | |
| 
 | |
| </p><div class="codeblock"><pre><i>-- Extract all files from the archive in the current "main" db to the</i>
 | |
| <i>-- current working directory. List files as they are extracted. </i>
 | |
| .ar --extract --verbose
 | |
| 
 | |
| <i>-- Extract file "file1" from archive "ar.db" to directory "dir1".</i>
 | |
| .ar fCx ar.db dir1 file1
 | |
| </pre></div>
 | |
| 
 | |
| <h2 id="_sqlite_archive_list_command_"><span>16.3. </span> SQLite Archive List Command </h2>
 | |
| 
 | |
| <p>List the contents of the archive. If no arguments are specified, then all
 | |
| files are listed. Otherwise, only those specified as arguments are. Currently,
 | |
| the --verbose option does not change the behaviour of this command. That may
 | |
| change in the future.
 | |
| 
 | |
| </p><div class="codeblock"><pre><i>-- List contents of archive in current "main" db.</i>.
 | |
| .ar --list
 | |
| </pre></div>
 | |
| 
 | |
| <a name="arinsup"></a>
 | |
| 
 | |
| <h2 id="_sqlite_archive_insert_and_update_commands_"><span>16.4. </span> SQLite Archive Insert And Update Commands </h2>
 | |
| 
 | |
| <p> The --update and --insert commands work like --create command, except that 
 | |
| they do not delete the current archive before commencing. New versions of
 | |
| files silently replace existing files with the same names, but otherwise
 | |
| the initial contents of the archive (if any) remain intact.
 | |
| 
 | |
| </p><p> For the --insert command, all files listed are inserted into the archive.
 | |
| For the --update command, files are only inserted if they do not previously
 | |
| exist in the archive, or if their "mtime" or "mode" is different from what
 | |
| is currently in the archive.
 | |
| 
 | |
| </p><p> Compatibility node:  Prior to SQLite version 3.28.0 (2019-04-16) only
 | |
| the --update option was supported but that option worked like --insert in that
 | |
| it always reinserted every file regardless of whether or not it had changed.
 | |
| 
 | |
| </p><h2 id="_operations_on_zip_archives_"><span>16.5. </span> Operations On ZIP Archives </h2>
 | |
| 
 | |
| <p>If FILE is a ZIP archive rather than an SQLite Archive, the ".archive"
 | |
| command and the "-A" command-line option still work.  This is accomplished
 | |
| using of the <a href="zipfile.html">zipfile</a> extension.
 | |
| Hence, the following commands are roughly equivalent,
 | |
| differing only in output formatting:
 | |
| 
 | |
| </p><table striped="1" style="margin:1em auto; width:80%; border-spacing:0">
 | |
|   <tr style="text-align:left"><th>Traditional Command</th><th>Equivalent sqlite3.exe Command
 | |
|   </th></tr><tr style="text-align:left;background-color:#DDDDDD"><td>unzip archive.zip</td><td>sqlite3 -Axf archive.zip
 | |
|   </td></tr><tr style="text-align:left"><td>unzip -l archive.zip</td><td>sqlite3 -Atvf archive.zip
 | |
|   </td></tr><tr style="text-align:left;background-color:#DDDDDD"><td>zip -r archive2.zip dir</td><td>sqlite3 -Acf archive2.zip dir
 | |
| </td></tr></table>
 | |
| 
 | |
| <h2 id="_sql_used_to_implement_sqlite_archive_operations_"><span>16.6. </span> SQL Used To Implement SQLite Archive Operations </h2>
 | |
| 
 | |
| <p>The various SQLite Archive Archive commands are implemented using SQL statements.
 | |
| Application developers can easily add SQLite Archive Archive reading and writing
 | |
| support to their own projects by running the appropriate SQL.
 | |
| 
 | |
| </p><p>To see what SQL statements are used to implement an SQLite Archive
 | |
| operation, add the --dryrun or -n option.  This causes the SQL to be
 | |
| displayed but inhibits the execution of the SQL.
 | |
| 
 | |
| </p><p>The SQL statements used to implement SQLite Archive operations make use of
 | |
| various <a href="loadext.html">loadable extensions</a>.  These extensions are all available in
 | |
| the <a href="https://sqlite.org/src">SQLite source tree</a> in the
 | |
| <a href="https://sqlite.org/src/file/ext/misc">ext/misc/ subfolder</a>.
 | |
| The extensions needed for full SQLite Archive support include:
 | |
| 
 | |
| </p><ol>
 | |
| <li><p>
 | |
| <a href="https://sqlite.org/src/file/ext/misc/fileio.c">fileio.c</a> —
 | |
| This extension adds SQL functions readfile() and writefile() for
 | |
| reading and writing content from files on disk.  The fileio.c
 | |
| extension also includes fsdir() table-valued function for listing
 | |
| the contents of a directory and the lsname() function for converting
 | |
| numeric st_mode integers from the stat() system call into human-readable
 | |
| strings after the fashion of the "ls -l" command.
 | |
| 
 | |
| </p></li><li><p>
 | |
| <a href="https://sqlite.org/src/file/ext/misc/sqlar.c">sqlar.c</a> —
 | |
| This extension adds the sqlar_compress() and sqlar_uncompress()
 | |
| functions that are needed to compress and uncompress file content
 | |
| as it is insert and extracted from an SQLite Archive.
 | |
| 
 | |
| </p></li><li><p>
 | |
| <a href="zipfile.html">zipfile.c</a> —
 | |
| This extension implements the "zipfile(FILE)" table-valued function
 | |
| which is used to read ZIP archives.  This extension is only needed
 | |
| when reading ZIP archives instead of SQLite archives.
 | |
| 
 | |
| </p></li><li><p>
 | |
| <a href="https://sqlite.org/src/file/ext/misc/appendvfs.c">appendvfs.c</a> —
 | |
| This extension implements a new <a href="vfs.html">VFS</a> that allows an SQLite database
 | |
| to be appended to some other file, such as an executable.  This
 | |
| extension is only needed if the --append option to the .archive
 | |
| command is used.
 | |
| </p></li></ol>
 | |
| 
 | |
| <a name="param"></a>
 | |
| 
 | |
| <h1 id="sql_parameters"><span>17. </span>SQL Parameters</h1>
 | |
| 
 | |
| <p>SQLite allows <a href="lang_expr.html#varparam">bound parameters</a> to appear in an SQL statement anywhere
 | |
| that a literal value is allowed.  The values for these parameters are set
 | |
| using the <a href="c3ref/bind_blob.html">sqlite3_bind_...()</a> family of APIs.
 | |
| 
 | |
| </p><p>Parameters can be either named or unnamed.  An unnamed parameter is a single
 | |
| question mark ("?").  Named parameters are a "?" followed immediately by a number
 | |
| (ex: "?15" or "?123") or one of the characters "$", ":", or "@" followed by an
 | |
| alphanumeric name (ex: "$var1", ":xyz", "@bingo").
 | |
| 
 | |
| </p><p>This command-line shell leaves unnamed parameters unbound, meaning that they
 | |
| will have a value of an SQL NULL, but named parameters might be assigned values.
 | |
| If there exists a TEMP table named "sqlite_parameters" with a schema like this:
 | |
| 
 | |
| </p><div class="codeblock"><pre>CREATE TEMP TABLE sqlite_parameters(
 | |
|   key TEXT PRIMARY KEY,
 | |
|   value ANY
 | |
| ) WITHOUT ROWID;
 | |
| </pre></div>
 | |
| 
 | |
| <p>And if there is an entry in that table where the key column exactly matches
 | |
| the name of parameter (including the initial "?", "$", ":", or "@" character)
 | |
| then the parameter is assigned the value of the value column.  If no entry exists,
 | |
| the parameter defaults to NULL.
 | |
| 
 | |
| </p><p>The ".parameter" command exists to simplify managing this table.  The
 | |
| ".parameter init" command (often abbreviated as just ".param init") creates
 | |
| the temp.sqlite_parameters table if it does not already exist.  The ".param list"
 | |
| command shows all entries in the temp.sqlite_parameters table.  The ".param clear"
 | |
| command drops the temp.sqlite_parameters table.  The ".param set KEY VALUE" and
 | |
| ".param unset KEY" commands create or delete entries from the 
 | |
| temp.sqlite_parameters table.
 | |
| 
 | |
| </p><p>The temp.sqlite_parameters table only provides values for parameters in the
 | |
| command-line shell.  The temp.sqlite_parameter table has no effect on queries
 | |
| that are run directly using the SQLite C-language API.  Individual applications
 | |
| are expected to implement their own parameter binding.  You can search for 
 | |
| "sqlite_parameters" in the 
 | |
| <a href="https://sqlite.org/src/file/src/shell.c.in">command-line shell source code</a>
 | |
| to see how the command-line shell does parameter binding, and use that as
 | |
| a hint for how to implement it yourself.
 | |
| 
 | |
| <a name="expert"></a>
 | |
| 
 | |
| </p><h1 id="index_recommendations_sqlite_expert_"><span>18. </span>Index Recommendations (SQLite Expert)</h1>
 | |
| 
 | |
| <p><b>Note: This command is experimental. It may be removed or the 
 | |
| interface modified in incompatible ways at some point in the future.
 | |
| 
 | |
| </b></p><p>For most non-trivial SQL databases, the key to performance is creating
 | |
| the right SQL indexes. In this context "the right SQL indexes" means those
 | |
| that cause the queries that an application needs to optimize run fast. The
 | |
| ".expert" command can assist with this by proposing indexes that might
 | |
| assist with specific queries, were they present in the database.
 | |
| 
 | |
| </p><p>The ".expert" command is issued first, followed by the SQL query 
 | |
| on a separate line. For example, consider the following session:
 | |
| 
 | |
| </p><div class="codeblock"><pre>sqlite> CREATE TABLE x1(a, b, c);                  <i>-- Create table in database </i>
 | |
| sqlite> .expert
 | |
| sqlite> SELECT * FROM x1 WHERE a=? AND b>?;        <i>-- Analyze this SELECT </i>
 | |
| CREATE INDEX x1_idx_000123a7 ON x1(a, b);
 | |
| 
 | |
| 0|0|0|SEARCH TABLE x1 USING INDEX x1_idx_000123a7 (a=? AND b>?)
 | |
| 
 | |
| sqlite> CREATE INDEX x1ab ON x1(a, b);             <i>-- Create the recommended index </i>
 | |
| sqlite> .expert
 | |
| sqlite> SELECT * FROM x1 WHERE a=? AND b>?;        <i>-- Re-analyze the same SELECT </i>
 | |
| (no new indexes)
 | |
| 
 | |
| 0|0|0|SEARCH TABLE x1 USING INDEX x1ab (a=? AND b>?)
 | |
| </pre></div>
 | |
| 
 | |
| <p>In the above, the user creates the database schema (a single table - "x1"),
 | |
| and then uses the ".expert" command to analyze a query, in this case 
 | |
| "SELECT * FROM x1 WHERE a=? AND b>?". The shell tool recommends that the
 | |
| user create a new index (index "x1_idx_000123a7") and outputs the plan
 | |
| that the query would use in <a href="eqp.html">EXPLAIN QUERY PLAN</a> format. The user then creates
 | |
| an index with an equivalent schema and runs the analysis on the same query
 | |
| again. This time the shell tool does not recommend any new indexes, and 
 | |
| outputs the plan that SQLite will use for the query given the existing 
 | |
| indexes.
 | |
| 
 | |
| </p><p>The ".expert" command accepts the following options:
 | |
| 
 | |
| </p><table striped="1" style="margin:1em auto; width:80%; border-spacing:0">
 | |
| <tr style="text-align:left"><th> Option </th><th> Purpose
 | |
| </th></tr><tr style="text-align:left;background-color:#DDDDDD"><td> --verbose 
 | |
|     </td><td> If present, output a more verbose report for each query analyzed.
 | |
| </td></tr><tr style="text-align:left"><td> --sample PERCENT 
 | |
|     </td><td> By default, the ".expert" command recommends indexes based on the
 | |
|          query and database schema alone. This is similar to the way the
 | |
|          <a href="optoverview.html">SQLite query planner</a> selects indexes for queries if the user has not
 | |
|          run the <a href="lang_analyze.html">ANALYZE</a> command on the database to generate data
 | |
|          distribution statistics. 
 | |
|          <div style="margin-top:1ex">
 | |
|          If this option is passed a non-zero argument, the ".expert" command
 | |
|          generates similar data distribution statistics for all indexes
 | |
|          considered based on PERCENT percent of the rows currently stored in
 | |
|          each database table. For databases with unusual data distributions,
 | |
|          this may lead to better index recommendations, particularly if the
 | |
|          application intends to run ANALYZE.
 | |
|          <div style="margin-top:1ex">
 | |
|          For small databases and modern CPUs, there is usually no reason not
 | |
|          to pass "--sample 100". However, gathering data distribution
 | |
|          statistics can be expensive for large database tables. If the
 | |
|          operation is too slow, try passing a smaller value for the --sample
 | |
|          option.
 | |
| </div></div></td></tr></table>
 | |
| 
 | |
| <p>Th functionality described in this section may be integrated into other
 | |
| applications or tools using the 
 | |
| <a href="http://www.sqlite.org/src/dir?ci=trunk&name=ext/expert">
 | |
| SQLite expert extension</a> code.
 | |
| 
 | |
| <a name="dotother"></a>
 | |
| 
 | |
| </p><h1 id="other_dot_commands"><span>19. </span>Other Dot Commands</h1>
 | |
| 
 | |
| <p>There are many other dot-commands available in the command-line
 | |
| shell.  See the ".help" command for a complete list for any particular
 | |
| version and build of SQLite.
 | |
| 
 | |
| <a name="insh"></a>
 | |
| 
 | |
| </p><h1 id="using_sqlite3_in_a_shell_script"><span>20. </span>Using sqlite3 in a shell script</h1>
 | |
| 
 | |
| <p>
 | |
| One way to use sqlite3 in a shell script is to use "echo" or
 | |
| "cat" to generate a sequence of commands in a file, then invoke sqlite3
 | |
| while redirecting input from the generated command file.  This
 | |
| works fine and is appropriate in many circumstances.  But as
 | |
| an added convenience, sqlite3 allows a single SQL command to be
 | |
| entered on the command line as a second argument after the
 | |
| database name.  When the sqlite3 program is launched with two
 | |
| arguments, the second argument is passed to the SQLite library
 | |
| for processing, the query results are printed on standard output
 | |
| in list mode, and the program exits.  This mechanism is designed
 | |
| to make sqlite3 easy to use in conjunction with programs like
 | |
| "awk".  For example:</p>
 | |
| 
 | |
| <div class="codeblock"><pre>$ <b>sqlite3 ex1 'select * from tbl1' |</b>
 | |
| > <b> awk '{printf "<tr><td>%s<td>%s\n",$1,$2 }'</b>
 | |
| <tr><td>hello<td>10
 | |
| <tr><td>goodbye<td>20
 | |
| $
 | |
| </pre></div>
 | |
| 
 | |
| <a name="endsh"></a>
 | |
| 
 | |
| <h1 id="ending_shell_commands"><span>21. </span>Ending shell commands</h1>
 | |
| 
 | |
| <p>
 | |
| SQLite commands are normally terminated by a semicolon.  In the shell 
 | |
| you can also use the word "GO" (case-insensitive) or a slash character 
 | |
| "/" on a line by itself to end a command.  These are used by SQL Server 
 | |
| and Oracle, respectively.  These won't work in <b>sqlite3_exec()</b>, 
 | |
| because the shell translates these into a semicolon before passing them 
 | |
| to that function.</p>
 | |
| 
 | |
| 
 | |
| <a name="compiling"></a>
 | |
| 
 | |
| <h1 id="compiling_the_sqlite3_program_from_sources"><span>22. </span>Compiling the sqlite3 program from sources</h1>
 | |
| 
 | |
| <p>
 | |
| To compile the command-line shell on unix systems and on Windows with MinGW,
 | |
| the usual configure-make command works:
 | |
| 
 | |
| </p><div class="codeblock"><pre>sh configure; make
 | |
| </pre></div>
 | |
| 
 | |
| <p>
 | |
| The configure-make works whether your are building from the canonical sources
 | |
| from the source tree, or from an amalgamated bundle.  There are few
 | |
| dependencies.  When building from canonical sources, a working 
 | |
| <a href="https://www.tcl.tk/man/tcl8.3/UserCmd/tclsh.htm">tclsh</a> is required.
 | |
| If using an amalgamation bundle, all the preprocessing work normally 
 | |
| done by tclsh will have already been carried out and only normal build
 | |
| tools are required.
 | |
| 
 | |
| </p><p>
 | |
| A working <a href="https://zlib.net">zlib compression library</a> is
 | |
| needed in order for the <a href="cli.html#sqlar">.archive command</a> to operate.
 | |
| 
 | |
| </p><p>
 | |
| On Windows with MSVC, use nmake with the Makefile.msc:
 | |
| 
 | |
| </p><div class="codeblock"><pre>nmake /f Makefile.msc
 | |
| </pre></div>
 | |
| 
 | |
| <p>
 | |
| For correct operation of the <a href="cli.html#sqlar">.archive command</a>, make a copy of the
 | |
| <a href="https://zlib.net">zlib source code</a> into the compat/zlib subdirectory 
 | |
| of the source tree and compile this way:
 | |
| 
 | |
| </p><div class="codeblock"><pre>nmake /f Makefile.msc USE_ZLIB=1
 | |
| </pre></div>
 | |
| 
 | |
| <h2 id="_do_it_yourself_builds_"><span>22.1. </span> Do-It-Yourself Builds </h2>
 | |
| 
 | |
| <p>
 | |
| The source code to the sqlite3 command line interface is in a single
 | |
| file named "shell.c".  The shell.c source file is generated from other
 | |
| sources, but most of the code for shell.c can be found in
 | |
| <a href="https://sqlite.org/src/file/src/shell.c.in">src/shell.c.in</a>.
 | |
| (Regenerate shell.c by typing "make shell.c" from the canonical source tree.)
 | |
| <a href="howtocompile.html">Compile</a> the shell.c file (together
 | |
| with the <a href="amalgamation.html">sqlite3 library source code</a>) to generate
 | |
| the executable.  For example:</p>
 | |
| 
 | |
| <div class="codeblock"><pre>gcc -o sqlite3 shell.c sqlite3.c -ldl -lpthread -lz -lm
 | |
| </pre></div>
 | |
| 
 | |
| <p>
 | |
| The following additional compile-time options are recommended in order to
 | |
| provide a full-featured command-line shell:
 | |
| 
 | |
| </p><ul>
 | |
| <li> <a href="compile.html#threadsafe">-DSQLITE_THREADSAFE=0</a>
 | |
| </li><li> <a href="compile.html#enable_explain_comments">-DSQLITE_ENABLE_EXPLAIN_COMMENTS</a>
 | |
| </li><li> <a href="compile.html#have_zlib">-DSQLITE_HAVE_ZLIB</a>
 | |
| </li><li> <a href="compile.html#introspection_pragmas">-DSQLITE_INTROSPECTION_PRAGMAS</a>
 | |
| </li><li> <a href="compile.html#enable_unknown_sql_function">-DSQLITE_ENABLE_UNKNOWN_SQL_FUNCTION</a>
 | |
| </li><li> <a href="compile.html#enable_stmtvtab">-DSQLITE_ENABLE_STMTVTAB</a>
 | |
| </li><li> <a href="compile.html#enable_dbpage_vtab">-DSQLITE_ENABLE_DBPAGE_VTAB</a>
 | |
| </li><li> <a href="compile.html#enable_dbstat_vtab">-DSQLITE_ENABLE_DBSTAT_VTAB</a>
 | |
| </li><li> <a href="compile.html#enable_offset_sql_func">-DSQLITE_ENABLE_OFFSET_SQL_FUNC</a>
 | |
| </li><li> <a href="compile.html#enable_json1">-DSQLITE_ENABLE_JSON1</a>
 | |
| </li><li> <a href="compile.html#enable_rtree">-DSQLITE_ENABLE_RTREE</a>
 | |
| </li><li> <a href="compile.html#enable_fts4">-DSQLITE_ENABLE_FTS4</a>
 | |
| </li><li> <a href="compile.html#enable_fts5">-DSQLITE_ENABLE_FTS5</a>
 | |
| </li></ul>
 | |
| 
 |