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
|
<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01//EN" "http://www.w3.org/TR/html4/strict.dtd">
<html><head>
<meta http-equiv="content-type" content="text/html; charset=UTF-8">
<title>Command Line Shell For SQLite</title>
<style type="text/css">
body {
margin: auto;
font-family: Verdana, sans-serif;
padding: 8px 1%;
}
a { color: #044a64 }
a:visited { color: #734559 }
.logo { position:absolute; margin:3px; }
.tagline {
float:right;
text-align:right;
font-style:italic;
width:300px;
margin:12px;
margin-top:58px;
}
.menubar {
clear: both;
border-radius: 8px;
background: #044a64;
padding: 0px;
margin: 0px;
cell-spacing: 0px;
}
.toolbar {
text-align: center;
line-height: 1.6em;
margin: 0;
padding: 0px 8px;
}
.toolbar a { color: white; text-decoration: none; padding: 6px 12px; }
.toolbar a:visited { color: white; }
.toolbar a:hover { color: #044a64; background: white; }
.content { margin: 5%; }
.content dt { font-weight:bold; }
.content dd { margin-bottom: 25px; margin-left:20%; }
.content ul { padding:0px; padding-left: 15px; margin:0px; }
/* Things for "fancyformat" documents start here. */
.fancy img+p {font-style:italic}
.fancy .codeblock i { color: darkblue; }
.fancy h1,.fancy h2,.fancy h3,.fancy h4 {font-weight:normal;color:#044a64}
.fancy h2 { margin-left: 10px }
.fancy h3 { margin-left: 20px }
.fancy h4 { margin-left: 30px }
.fancy th {white-space:nowrap;text-align:left;border-bottom:solid 1px #444}
.fancy th, .fancy td {padding: 0.2em 1ex; vertical-align:top}
.fancy #toc a { color: darkblue ; text-decoration: none }
.fancy .todo { color: #AA3333 ; font-style : italic }
.fancy .todo:before { content: 'TODO:' }
.fancy p.todo { border: solid #AA3333 1px; padding: 1ex }
.fancy img { display:block; }
.fancy :link:hover, .fancy :visited:hover { background: wheat }
.fancy p,.fancy ul,.fancy ol { margin: 1em 5ex }
.fancy li p { margin: 1em 0 }
/* End of "fancyformat" specific rules. */
</style>
</head>
<body>
<div><!-- container div to satisfy validator -->
<a href="index.html">
<img class="logo" src="images/sqlite370_banner.gif" alt="SQLite Logo"
border="0"></a>
<div><!-- IE hack to prevent disappearing logo--></div>
<div class="tagline">Small. Fast. Reliable.<br>Choose any three.</div>
<table width=100% class="menubar"><tr>
<td width=100%>
<div class="toolbar">
<a href="about.html">About</a>
<a href="sitemap.html">Sitemap</a>
<a href="docs.html">Documentation</a>
<a href="download.html">Download</a>
<a href="copyright.html">License</a>
<a href="news.html">News</a>
<a href="support.html">Support</a>
</div>
<script>
gMsg = "Search SQLite Docs..."
function entersearch() {
var q = document.getElementById("q");
if( q.value == gMsg ) { q.value = "" }
q.style.color = "black"
q.style.fontStyle = "normal"
}
function leavesearch() {
var q = document.getElementById("q");
if( q.value == "" ) {
q.value = gMsg
q.style.color = "#044a64"
q.style.fontStyle = "italic"
}
}
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>
<td>
<div style="padding:0 1em 0px 0;white-space:nowrap">
<form name=f method="GET" action="http://www.sqlite.org/search">
<input id=q name=q type=text
onfocus="entersearch()" onblur="leavesearch()" style="width:24ex;padding:1px 1ex; border:solid white 1px; font-size:0.9em ; font-style:italic;color:#044a64;" value="Search SQLite Docs...">
<input type=submit value="Go" style="border:solid white 1px;background-color:#044a64;color:white;font-size:0.9em;padding:0 1ex">
</form>
</div>
</table>
<div class=startsearch></div>
<h1 align=center>
Command Line Shell For SQLite
</h1>
<p>The SQLite project provides a simple command-line utility 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. This document provides a brief
introduction on how to use the <b>sqlite3</b> program.
<h3>Getting Started</h3>
<p>To start the <b>sqlite3</b> program, just type "sqlite3" optionally
followed by the name the file that holds the SQLite database. If the
file does not exist, a new database file with the given name will be
created automatically. If no database file is specified, a temporary
database is created, then deleted when the "sqlite3" program exits.
<p>When started, 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>
<blockquote><pre>$ <b>sqlite3 ex1</b>
SQLite version 3.8.5 2014-05-29 12:36:14
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></blockquote>
<p>You can terminate the sqlite3 program by typing your systems
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>
<blockquote><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></blockquote>
<h3>Double-click Startup On Windows</h3>
<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. Note,
however, that by default this SQLite session is using an in-memory database,
not a file on disk, and so all changes will be lost when the session exits.
To use a persistent disk file as the database, enter the ".open" command
immediately after the terminal window starts up:
<blockquote><pre>SQLite version 3.8.5 2014-05-29 12:36:14
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></blockquote>
<p>The example above causes the database file named "ex1.db" to be opened
and used, and 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 in-memory
storage, then save that database into a disk file using the ".save" command:
<blockquote><pre>SQLite version 3.8.5 2014-05-29 12:36:14
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></blockquote>
<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.
<h3>Special commands to sqlite3</h3>
<p>
Most of the time, sqlite3 just reads lines of input and passes them
on to the SQLite library for execution.
But if an input line begins with a dot ("."), then
that line is 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.
</p>
<p>
For a listing of the available dot commands, you can enter ".help"
at any time. For example:
</p>
<blockquote><pre>sqlite> <b>.help</b>
.backup ?DB? FILE Backup DB (default "main") to FILE
.bail on|off Stop after hitting an error. Default OFF
.clone NEWDB Clone data into NEWDB from the existing database
.databases List names and files of attached databases
.dump ?TABLE? ... Dump the database in an SQL text format
If TABLE specified, only dump tables matching
LIKE pattern TABLE.
.echo on|off Turn command echo on or off
.eqp on|off Enable or disable automatic EXPLAIN QUERY PLAN
.exit Exit this program
.explain ?on|off? Turn output mode suitable for EXPLAIN on or off.
With no args, it turns EXPLAIN on.
.fullschema Show schema and the content of sqlite_stat tables
.headers on|off Turn display of headers on or off
.help Show this message
.import FILE TABLE Import data from FILE into TABLE
.indices ?TABLE? Show names of all indices
If TABLE specified, only show indices for tables
matching LIKE pattern TABLE.
.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 where MODE is one of:
csv Comma-separated values
column Left-aligned columns. (See .width)
html HTML <table> code
insert SQL insert statements for TABLE
line One value per line
list Values delimited by .separator string
tabs Tab-separated values
tcl TCL list elements
.nullvalue STRING Use STRING in place of NULL values
.once FILENAME Output for the next SQL command only to FILENAME
.open ?FILENAME? Close existing database and reopen FILENAME
.output ?FILENAME? Send output to FILENAME or stdout
.print STRING... Print literal STRING
.prompt MAIN CONTINUE Replace the standard prompts
.quit Exit this program
.read FILENAME Execute SQL in FILENAME
.restore ?DB? FILE Restore content of DB (default "main") from FILE
.save FILE Write in-memory database into FILE
.schema ?TABLE? Show the CREATE statements
If TABLE specified, only show tables matching
LIKE pattern TABLE.
.separator STRING ?NL? Change separator used by output mode and .import
NL is the end-of-line mark for CSV
.shell CMD ARGS... Run CMD ARGS... in a system shell
.show Show the current values for various settings
.stats on|off Turn stats on or off
.system CMD ARGS... Run CMD ARGS... in a system shell
.tables ?TABLE? List names of tables
If TABLE specified, only list tables matching
LIKE pattern TABLE.
.timeout MS Try opening locked tables for MS milliseconds
.timer on|off Turn SQL timer on or off
.trace FILE|off Output each SQL statement as it is run
.vfsname ?AUX? Print the name of the VFS stack
.width NUM1 NUM2 ... Set column widths for "column" mode
Negative values right-justify
sqlite></pre></blockquote>
<h3>Rules for "dot-commands"</h3>
<p>Ordinary SQL statements are free-form, and can be
spread across multiple lines, and can have whitespace and
comments anywhere. But dot-commands are
more restrictive:
<ul>
<li>A dot-command must begin with the "." at the left margin
with no preceding whitespace.
<li>The dot-command must be entirely contained on a single input line.
<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>Dot-commands do not recognize comments.
</ul>
<p>And, of course, it is important to remember that 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>.
<h3>Changing Output Formats</h3>
<p>The sqlite3 program is able to show the results of a query
in eight different formats: "csv", "column", "html", "insert",
"line", "list", "tabs", and "tcl".
You can use the ".mode" dot command to switch between these output
formats.</p>
<p>The default output mode is "list". In
list mode, each record of a query result is written on one line of
output and each column within that record 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>
<blockquote><pre>sqlite> <b>.mode list</b>
sqlite> <b>select * from tbl1;</b>
hello|10
goodbye|20
sqlite></pre></blockquote>
<p>You can use the ".separator" dot command to change the separator
for list mode. For example, to change the separator to a comma and
a space, you could do this:</p>
<blockquote><pre>sqlite> <b>.separator ", "</b>
sqlite> <b>select * from tbl1;</b>
hello, 10
goodbye, 20
sqlite></pre></blockquote>
<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>
<blockquote><pre>sqlite> <b>.mode line</b>
sqlite> <b>select * from tbl1;</b>
one = hello
two = 10
one = goodbye
two = 20
sqlite></pre></blockquote>
<p>In column mode, each record is shown on a separate line with the
data aligned in columns. For example:</p>
<blockquote><pre>sqlite> <b>.mode column</b>
sqlite> <b>select * from tbl1;</b>
one two
---------- ----------
hello 10
goodbye 20
sqlite></pre></blockquote>
<p>By default, each column is between 1 and 10 characters wide, depending
on the column header name and the width of the first column of data.
Data that is too wide to fit in a column is truncated. You can
adjust the column widths using the ".width" command. Like this:</p>
<blockquote><pre>sqlite> <b>.width 12 6</b>
sqlite> <b>select * from tbl1;</b>
one two
------------ ------
hello 10
goodbye 20
sqlite></pre></blockquote>
<p>The ".width" command in the example above sets the width of the first
column to 12 and the width of the second column to 6. All other column
widths were unaltered. You can gives as many arguments to ".width" as
necessary to specify the widths of as many columns as are in your
query results.</p>
<p>If you specify a column a width of 0, then the column
width is automatically adjusted to be the maximum of three
numbers: 10, the width of the header, and the width of the
first row of data. This makes the column width self-adjusting.
The default width setting for every column is this
auto-adjusting 0 value.</p>
<p>You can specify a negative column width to get
right-justified columns.</p>
<p>The column labels that appear on the first two lines of output
can be turned on and off using the ".header" dot command. In the
examples above, the column labels are on. To turn them off you
could do this:</p>
<blockquote><pre>sqlite> <b>.header off</b>
sqlite> <b>select * from tbl1;</b>
hello 10
goodbye 20
sqlite></pre></blockquote>
<p>Another useful output mode is "insert". In insert mode, the output
is formatted to look like SQL INSERT statements. You can 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>
<blockquote><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></blockquote>
<p>The last output mode is "html". In this mode, sqlite3 writes
the results of the query as an XHTML table. The beginning
<TABLE> and the ending </TABLE> are not written, but
all of the intervening <TR>s, <TH>s, and <TD>s
are. The html output mode is envisioned as being useful for
CGI.</p>
<a name="explain"></a>
<p>The ".explain" dot command can be used to set the output mode
to "column" and to set the column widths to values that are reasonable
for looking at the output of an <a href="lang_explain.html">EXPLAIN</a> command. The EXPLAIN command
is an SQLite-specific SQL extension that is useful for debugging. If any
regular SQL is prefaced by EXPLAIN, then the SQL command is parsed and
analyzed but is not executed. Instead, the sequence of virtual machine
instructions that would have been used to execute the SQL command are
returned like a query result. For example:</p>
<blockquote><pre>sqlite> <b>.explain</b>
sqlite> <b>explain delete from tbl1 where two<20;</b>
addr opcode p1 p2 p3 p4 p5 comment
---- ------------- ---- ---- ---- ------------- -- -------------
0 Trace 0 0 0 00
1 Goto 0 18 0 00
2 Null 0 1 0 00 r[1]=NULL
3 OpenRead 0 2 0 2 00 root=2 iDb=0; tbl1
4 Rewind 0 10 0 00
5 Column 0 1 2 00 r[2]=tbl1.two
6 Ge 3 9 2 (BINARY) 6a if r[3]>=r[2] goto 10
7 Rowid 0 4 0 00 r[4]=rowid
8 RowSetAdd 1 4 0 00 rowset(1)=r[4]
9 Next 0 7 0 01
10 Close 0 0 0 00
11 OpenWrite 0 2 0 2 00 root=2 iDb=0; tbl1
12 RowSetRead 1 16 4 00 r[4]=rowset(1)
13 NotExists 0 12 4 1 00 intkey=r[4]
14 Delete 0 1 0 tbl1 00
15 Goto 0 12 0 00
16 Close 0 0 0 00
17 Halt 0 0 0 00
18 Transaction 0 1 0 00
19 VerifyCookie 0 1 0 00
20 TableLock 0 2 1 tbl1 00 iDb=0 root=2 write=1
21 Integer 20 3 0 00 r[3]=20
22 Goto 0 2 0 00</pre></blockquote>
<p>Notice how the shell changes the indentation of some opcodes to
help show the loop structure of the <a href="opcode.html">VDBE</a> program.
<h3>Writing results to a file</h3>
<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 returning the console. Use .output with no arguments to
begin writing to standard output again. For example:</p>
<blockquote><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></blockquote>
<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>
<blockquote><pre>sqlite3> <b>.once '|open -f'</b>
sqlite3> <b>SELECT * FROM bigTable;</b></pre></blockquote>
<a name="fileio"></a>
<h4>File I/O Functions</h4>
<p>The command-line shell adds two <a href="c3ref/create_function.html">application-defined SQL functions</a> that
facilitate read content from a file into an table column, and writing the
content of a column into a file, respectively.
<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:
<blockquote><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></blockquote>
<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:
<blockquote><pre>sqlite> <b>SELECT writefile('icon.jpg',img) FROM images WHERE name='icon';</b></pre></blockquote>
<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>.
<h3>Querying the database schema</h3>
<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>
<p>For example, to see a list of the tables in the database, you
can enter ".tables".</p>
<blockquote><pre>sqlite> <b>.tables</b>
tbl1
tbl2
sqlite></pre></blockquote>
<p>The ".tables" command is similar to setting list mode then
executing the following query:</p>
<blockquote><pre>
SELECT name FROM sqlite_master
WHERE type IN ('table','view') AND name NOT LIKE 'sqlite_%'
UNION ALL
SELECT name FROM sqlite_temp_master
WHERE type IN ('table','view')
ORDER BY 1
</pre></blockquote>
<p>In fact, if you look at the source code to the sqlite3 program
(found in the source tree in the file src/shell.c) you'll find
a query very much like the above.</p>
<p>The ".indices" command works in a similar way to list all of
the indices for a particular table. The ".indices" command takes
a single argument which is the name of the table for which the
indices are desired. Last, but not least, is the ".schema" command.
With no arguments, the ".schema" command shows the original CREATE TABLE
and CREATE INDEX statements that were used to build the current database.
If you give the name of a table to ".schema", it shows the original
CREATE statement used to make that table and all if its indices.
We have:</p>
<blockquote><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></blockquote>
<p>The ".schema" command accomplishes the same thing as setting
list mode, then entering the following query:</p>
<blockquote><pre>
SELECT sql FROM
(SELECT * FROM sqlite_master UNION ALL
SELECT * FROM sqlite_temp_master)
WHERE type!='meta'
ORDER BY tbl_name, type DESC, name
</pre></blockquote>
<p>Or, if you give an argument to ".schema" because you only
want the schema for a single table, the query looks like this:</p>
<blockquote><pre>
SELECT sql FROM
(SELECT * FROM sqlite_master UNION ALL
SELECT * FROM sqlite_temp_master)
WHERE type!='meta' AND sql NOT NULL AND name NOT LIKE 'sqlite_%'
ORDER BY substr(type,2,1), name
</pre></blockquote>
<p>
You can supply an argument to the .schema command. If you do, the
query looks like this:
</p>
<blockquote><pre>
SELECT sql FROM
(SELECT * FROM sqlite_master UNION ALL
SELECT * FROM sqlite_temp_master)
WHERE tbl_name LIKE '%s'
AND type!='meta' AND sql NOT NULL AND name NOT LIKE 'sqlite_%'
ORDER BY substr(type,2,1), name
</pre></blockquote>
<p>The "%s" in the query is replace by your argument. This allows you
to view the schema for some subset of the database.</p>
<blockquote><pre>sqlite> <b>.schema %abc%</b></pre></blockquote>
<p>
Along these same lines,
the ".table" command also accepts a pattern as its first argument.
If you give an argument to the .table command, a "%" is both
appended and prepended and a LIKE clause is added to the query.
This allows you to list only those tables that match a particular
pattern.</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>
<blockquote><pre>sqlite> <b>.databases</b></pre></blockquote>
<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>
<h3>CSV Import</h3>
<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>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.
<blockquote><pre>sqlite> <b>.mode csv</b>
sqlite> <b>.import C:/work/somedata.csv tab1</b></pre></blockquote>
<p>There are two cases to consider: (1) Table "tab1" does not previously
exist and (2) table "tab1" does already exist.
<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>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, that row will be
read as data and inserted into the table. To avoid this, make sure that
table does not previously exist.
<a name="csvout"></a>
<h3>CSV Export</h3>
<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.
<blockquote><pre>sqlite> <b>.header 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></blockquote>
<p>In the example above, the ".header 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 ".header off" instead. (The ".header off" setting is
the default and can be omitted if the headers have not been previously
turned on.)
<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>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. That command only works as shown on Windows. The
equivalent line on a Mac would be ".system open /work/dataout.csv".
On Linux and other unix systems you will need to enter something like
".system libreoffice /work/dataout.csv", substituting your preferred
CSV viewing program for "libreoffice".
<h3>Converting An Entire Database To An ASCII Text File</h3>
<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>
<blockquote><pre>$ <b>echo '.dump' | sqlite3 ex1 | gzip -c >ex1.dump.gz</b></pre></blockquote>
<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>
<blockquote><pre>$ <b>zcat ex1.dump.gz | sqlite3 ex2</b></pre></blockquote>
<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>
<blockquote><pre>$ <b>createdb ex2</b>
$ <b>sqlite3 ex1 .dump | psql ex2</b></pre></blockquote>
<h3>Loading Extensions</h3>
<p>You can add new custom <a href="c3ref/create_function.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:
<blockquote><pre>sqlite> .load /path/to/my_extension</pre></blockquote>
<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>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>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.
<h3>Other Dot Commands</h3>
<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.
<h3>Using sqlite3 in a shell script</h3>
<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>
<blockquote><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></blockquote>
<h3>Ending shell commands</h3>
<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>
<h3>Compiling the sqlite3 program from sources</h3>
<p>
The source code to the sqlite3 command line interface is in a single
file named "shell.c" which you can
<a href="http://www.sqlite.org/src/finfo?name=src/shell.c">
download</a> from the SQLite website.
<a href="howtocompile.html">Compile</a> this file (together
with the <a href="amalgamation.html">sqlite3 library source code</a>) to generate
the executable. For example:</p>
<blockquote><pre>
gcc -o sqlite3 shell.c sqlite3.c -ldl -lpthread
</pre></blockquote>
|