Python SQLite3 Tutorial: Complete Guide to SQLite Database in Python
Updated on
You need to store structured data in your Python application. Maybe it is user settings, sensor readings, log entries, or a task list. You reach for a CSV file, but the data grows and queries become painful. You consider PostgreSQL or MySQL, but setting up a database server for a local tool or prototype feels like overkill. You just need a reliable way to store, query, and update structured data without the overhead.
This is exactly the problem SQLite solves. SQLite is a self-contained, serverless database engine that stores everything in a single file. Python ships with the sqlite3 module in the standard library, so there is nothing to install. You get full SQL support, ACID transactions, and the ability to handle datasets up to 281 terabytes -- all without running a server process or managing configuration files.
This guide walks through everything you need to use SQLite effectively in Python: from creating your first database to advanced queries, pandas integration, performance tuning, and a complete real-world project.
What Is SQLite and Why Use It?
SQLite is an embedded relational database engine. Unlike PostgreSQL or MySQL, it does not run as a separate server process. The entire database lives in a single file on disk (or in memory). The sqlite3 module in Python's standard library provides a DB-API 2.0 compliant interface to SQLite.
Key characteristics of SQLite:
- Zero configuration: No server setup, no users, no permissions to manage
- Serverless: The database engine runs in your application's process
- Single file: The entire database (tables, indexes, data) is one
.dbfile - Cross-platform: The database file works on any OS without conversion
- ACID compliant: Full transaction support with commit and rollback
- Lightweight: The library is about 750 KB -- smaller than most images
When to Use SQLite
| Use Case | SQLite | PostgreSQL/MySQL |
|---|---|---|
| Desktop/mobile apps | Best choice | Overkill |
| Prototyping | Best choice | Slower to set up |
| Embedded devices / IoT | Best choice | Not feasible |
| Unit testing | Best choice | Requires test server |
| Data analysis scripts | Good choice | Unnecessary overhead |
| Web app with < 100K daily visits | Works well | More scalable |
| High-concurrency web app | Not ideal | Best choice |
| Multiple write-heavy clients | Not ideal | Best choice |
SQLite handles most applications that do not require multiple simultaneous write connections. Android and iOS use SQLite as their default local database. Firefox, Chrome, and macOS use it internally. It is the most deployed database engine in the world.
Connecting to a Database
The sqlite3.connect() function creates a connection to a database file. If the file does not exist, SQLite creates it automatically. You can use pathlib to construct database file paths in a platform-independent way.
import sqlite3
# Connect to a database file (creates it if it doesn't exist)
conn = sqlite3.connect("myapp.db")
# Create a cursor to execute SQL statements
cursor = conn.cursor()
# Always close the connection when done
conn.close()In-Memory Databases
Use the special string :memory: to create a database that exists only in RAM. This is ideal for testing and temporary data processing.
import sqlite3
conn = sqlite3.connect(":memory:")
cursor = conn.cursor()
cursor.execute("CREATE TABLE test (id INTEGER, value TEXT)")
cursor.execute("INSERT INTO test VALUES (1, 'hello')")
cursor.execute("SELECT * FROM test")
print(cursor.fetchone()) # (1, 'hello')
conn.close() # Database is gone after thisUsing Context Managers
The recommended pattern uses a context manager (with statement) to ensure the connection closes properly, even if an error occurs. SQLite connections also auto-commit on success and auto-rollback on exception within a with block.
import sqlite3
# Connection as context manager handles commit/rollback
with sqlite3.connect("myapp.db") as conn:
cursor = conn.cursor()
cursor.execute("CREATE TABLE IF NOT EXISTS users (id INTEGER PRIMARY KEY, name TEXT)")
cursor.execute("INSERT INTO users (name) VALUES (?)", ("Alice",))
# Auto-commits if no exception
# Auto-rolls back if an exception occurs
# Note: the connection is NOT closed by 'with' -- it just commits/rolls back
# For full cleanup, close explicitly or use a wrapper:
conn.close()A clean helper function that handles both commit/rollback and closing:
import sqlite3
from contextlib import contextmanager
@contextmanager
def get_db(db_path="myapp.db"):
"""Context manager that commits on success, rolls back on error, and always closes."""
conn = sqlite3.connect(db_path)
try:
yield conn
conn.commit()
except Exception:
conn.rollback()
raise
finally:
conn.close()
# Usage
with get_db() as conn:
conn.execute("INSERT INTO users (name) VALUES (?)", ("Bob",))Creating Tables
Use CREATE TABLE to define the schema. SQLite supports a simplified type system with five storage classes.
SQLite Data Types
| Storage Class | Description | Python Equivalent |
|---|---|---|
NULL | Null value | None |
INTEGER | Signed integer (1, 2, 3, 4, 6, or 8 bytes) | int |
REAL | Floating point (8-byte IEEE float) | float |
TEXT | UTF-8 or UTF-16 string | str |
BLOB | Binary data, stored exactly as input | bytes |
SQLite uses dynamic typing. You can store any type in any column regardless of the declared type. The declared type is a hint, not a constraint. This is different from PostgreSQL and MySQL.
Creating a Table with Constraints
import sqlite3
conn = sqlite3.connect("myapp.db")
cursor = conn.cursor()
cursor.execute("""
CREATE TABLE IF NOT EXISTS employees (
id INTEGER PRIMARY KEY AUTOINCREMENT,
name TEXT NOT NULL,
email TEXT UNIQUE NOT NULL,
department TEXT DEFAULT 'General',
salary REAL CHECK(salary > 0),
hire_date TEXT NOT NULL,
is_active INTEGER DEFAULT 1
)
""")
conn.commit()
conn.close()Key constraints:
PRIMARY KEY: Unique identifier for each row.INTEGER PRIMARY KEYis an alias for the internal rowid.AUTOINCREMENT: Guarantees the rowid always increases (never reuses deleted IDs).NOT NULL: Column cannot contain NULL values.UNIQUE: No two rows can have the same value in this column.DEFAULT: Default value if none is provided during INSERT.CHECK: Validates data against a condition.
Creating Multiple Related Tables
import sqlite3
conn = sqlite3.connect("school.db")
cursor = conn.cursor()
# Enable foreign key enforcement (off by default in SQLite)
cursor.execute("PRAGMA foreign_keys = ON")
cursor.execute("""
CREATE TABLE IF NOT EXISTS students (
id INTEGER PRIMARY KEY AUTOINCREMENT,
name TEXT NOT NULL,
email TEXT UNIQUE
)
""")
cursor.execute("""
CREATE TABLE IF NOT EXISTS courses (
id INTEGER PRIMARY KEY AUTOINCREMENT,
title TEXT NOT NULL,
credits INTEGER DEFAULT 3
)
""")
cursor.execute("""
CREATE TABLE IF NOT EXISTS enrollments (
id INTEGER PRIMARY KEY AUTOINCREMENT,
student_id INTEGER NOT NULL,
course_id INTEGER NOT NULL,
grade TEXT,
enrolled_date TEXT DEFAULT CURRENT_DATE,
FOREIGN KEY (student_id) REFERENCES students(id) ON DELETE CASCADE,
FOREIGN KEY (course_id) REFERENCES courses(id) ON DELETE CASCADE,
UNIQUE(student_id, course_id)
)
""")
conn.commit()
conn.close()CRUD Operations
CRUD stands for Create, Read, Update, Delete -- the four basic operations for persistent storage.
INSERT: Adding Data
import sqlite3
conn = sqlite3.connect("myapp.db")
cursor = conn.cursor()
# Insert a single row
cursor.execute(
"INSERT INTO employees (name, email, department, salary, hire_date) VALUES (?, ?, ?, ?, ?)",
("Alice Johnson", "alice@company.com", "Engineering", 95000, "2024-01-15")
)
# Insert multiple rows with executemany
employees = [
("Bob Smith", "bob@company.com", "Marketing", 72000, "2024-03-01"),
("Carol White", "carol@company.com", "Engineering", 98000, "2023-11-20"),
("David Brown", "david@company.com", "Sales", 68000, "2024-06-10"),
("Eve Davis", "eve@company.com", "Engineering", 105000, "2023-08-05"),
]
cursor.executemany(
"INSERT INTO employees (name, email, department, salary, hire_date) VALUES (?, ?, ?, ?, ?)",
employees
)
# Get the last inserted row ID
print(f"Last inserted ID: {cursor.lastrowid}")
# Get the number of rows affected
print(f"Rows inserted: {cursor.rowcount}")
conn.commit()
conn.close()INSERT OR REPLACE (Upsert)
import sqlite3
conn = sqlite3.connect("myapp.db")
cursor = conn.cursor()
# Insert or update if email already exists
cursor.execute("""
INSERT INTO employees (name, email, department, salary, hire_date)
VALUES (?, ?, ?, ?, ?)
ON CONFLICT(email) DO UPDATE SET
name = excluded.name,
salary = excluded.salary
""", ("Alice Johnson", "alice@company.com", "Engineering", 100000, "2024-01-15"))
conn.commit()
conn.close()SELECT: Reading Data
import sqlite3
conn = sqlite3.connect("myapp.db")
cursor = conn.cursor()
# Select all rows
cursor.execute("SELECT * FROM employees")
all_rows = cursor.fetchall()
for row in all_rows:
print(row) # Returns tuples by default
# Select specific columns with a condition
cursor.execute(
"SELECT name, salary FROM employees WHERE department = ?",
("Engineering",)
)
engineers = cursor.fetchall()
for name, salary in engineers:
print(f"{name}: ${salary:,.0f}")
# Select with ordering and limit
cursor.execute("""
SELECT name, salary FROM employees
ORDER BY salary DESC
LIMIT 3
""")
top_earners = cursor.fetchall()
print("Top 3 earners:", top_earners)
conn.close()Getting Results as Dictionaries
By default, fetchall() returns tuples. To get dictionaries (column name as key), use sqlite3.Row:
import sqlite3
conn = sqlite3.connect("myapp.db")
conn.row_factory = sqlite3.Row # Set row factory
cursor = conn.cursor()
cursor.execute("SELECT * FROM employees WHERE department = ?", ("Engineering",))
for row in cursor.fetchall():
print(dict(row)) # Convert Row to dict
print(row["name"], row["salary"]) # Access by column name
conn.close()UPDATE: Modifying Data
import sqlite3
conn = sqlite3.connect("myapp.db")
cursor = conn.cursor()
# Update a single field
cursor.execute(
"UPDATE employees SET salary = ? WHERE email = ?",
(110000, "alice@company.com")
)
print(f"Rows updated: {cursor.rowcount}")
# Update with a calculation
cursor.execute("""
UPDATE employees
SET salary = salary * 1.10
WHERE department = 'Engineering' AND salary < 100000
""")
print(f"Engineers with raises: {cursor.rowcount}")
# Conditional update
cursor.execute("""
UPDATE employees
SET is_active = 0
WHERE hire_date < '2023-01-01'
""")
conn.commit()
conn.close()DELETE: Removing Data
import sqlite3
conn = sqlite3.connect("myapp.db")
cursor = conn.cursor()
# Delete specific rows
cursor.execute("DELETE FROM employees WHERE is_active = 0")
print(f"Rows deleted: {cursor.rowcount}")
# Delete with a subquery
cursor.execute("""
DELETE FROM enrollments
WHERE student_id NOT IN (SELECT id FROM students)
""")
# Delete all rows (truncate equivalent)
cursor.execute("DELETE FROM employees")
conn.commit()
conn.close()Parameterized Queries and SQL Injection Prevention
Never build SQL queries with string formatting or f-strings. Always use parameterized queries to prevent SQL injection attacks.
The Problem: SQL Injection
import sqlite3
# DANGEROUS: Never do this
user_input = "'; DROP TABLE employees; --"
query = f"SELECT * FROM employees WHERE name = '{user_input}'"
# This would execute: SELECT * FROM employees WHERE name = ''; DROP TABLE employees; --'The Solution: Parameterized Queries
SQLite3 supports two placeholder styles:
import sqlite3
conn = sqlite3.connect("myapp.db")
cursor = conn.cursor()
# Style 1: Question mark placeholders (positional)
cursor.execute(
"SELECT * FROM employees WHERE department = ? AND salary > ?",
("Engineering", 90000)
)
# Style 2: Named placeholders
cursor.execute(
"SELECT * FROM employees WHERE department = :dept AND salary > :min_salary",
{"dept": "Engineering", "min_salary": 90000}
)
# Named placeholders are clearer with many parameters
cursor.execute("""
INSERT INTO employees (name, email, department, salary, hire_date)
VALUES (:name, :email, :dept, :salary, :date)
""", {
"name": "Frank Green",
"email": "frank@company.com",
"dept": "Engineering",
"salary": 92000,
"date": "2025-09-01"
})
conn.commit()
conn.close()Parameterized queries handle escaping and quoting automatically. The database engine treats parameter values as data, never as SQL code. This eliminates SQL injection regardless of the input content.
Dynamic WHERE Clauses
Sometimes you need to build queries dynamically, for instance when filters are optional. Here is a safe pattern:
import sqlite3
def search_employees(department=None, min_salary=None, is_active=None):
conn = sqlite3.connect("myapp.db")
cursor = conn.cursor()
conditions = []
params = []
if department is not None:
conditions.append("department = ?")
params.append(department)
if min_salary is not None:
conditions.append("salary >= ?")
params.append(min_salary)
if is_active is not None:
conditions.append("is_active = ?")
params.append(is_active)
query = "SELECT * FROM employees"
if conditions:
query += " WHERE " + " AND ".join(conditions)
cursor.execute(query, params)
results = cursor.fetchall()
conn.close()
return results
# Usage
engineers = search_employees(department="Engineering", min_salary=90000)
active_staff = search_employees(is_active=1)
everyone = search_employees() # No filtersWorking with Transactions
A transaction groups multiple SQL operations into an atomic unit. Either all operations succeed (commit) or none of them take effect (rollback).
Manual Transaction Control
import sqlite3
conn = sqlite3.connect("myapp.db")
cursor = conn.cursor()
try:
# Transfer money between accounts
cursor.execute("UPDATE accounts SET balance = balance - 500 WHERE id = 1")
cursor.execute("UPDATE accounts SET balance = balance + 500 WHERE id = 2")
# Verify no negative balance
cursor.execute("SELECT balance FROM accounts WHERE id = 1")
balance = cursor.fetchone()[0]
if balance < 0:
raise ValueError("Insufficient funds")
conn.commit() # All good, save changes
print("Transfer complete")
except Exception as e:
conn.rollback() # Something went wrong, undo everything
print(f"Transfer failed: {e}")
finally:
conn.close()Autocommit and Isolation Levels
By default, sqlite3 operates in "deferred transaction" mode. You can change this behavior:
import sqlite3
# Default behavior: transactions are deferred
conn = sqlite3.connect("myapp.db")
# Autocommit mode (each statement is its own transaction)
conn = sqlite3.connect("myapp.db", isolation_level=None)
# Immediate locking (prevents concurrent write conflicts)
conn = sqlite3.connect("myapp.db")
conn.execute("BEGIN IMMEDIATE")
# ... your operations ...
conn.commit()Savepoints for Partial Rollbacks
Savepoints let you roll back part of a transaction without undoing everything:
import sqlite3
conn = sqlite3.connect("myapp.db")
cursor = conn.cursor()
try:
cursor.execute("INSERT INTO orders (customer_id, total) VALUES (1, 100)")
# Start a savepoint
cursor.execute("SAVEPOINT order_items")
try:
cursor.execute("INSERT INTO order_items (order_id, product, qty) VALUES (1, 'Widget', 5)")
cursor.execute("INSERT INTO order_items (order_id, product, qty) VALUES (1, 'Gadget', -1)")
# This might fail due to CHECK constraint
cursor.execute("RELEASE SAVEPOINT order_items")
except sqlite3.IntegrityError:
cursor.execute("ROLLBACK TO SAVEPOINT order_items")
print("Some items failed, but order was still created")
conn.commit()
except Exception:
conn.rollback()
finally:
conn.close()Fetching Data: fetchone, fetchall, fetchmany
The cursor object provides three methods for retrieving query results.
import sqlite3
conn = sqlite3.connect("myapp.db")
cursor = conn.cursor()
cursor.execute("SELECT * FROM employees ORDER BY salary DESC")
# fetchone: Get the next single row (or None if no more rows)
top_earner = cursor.fetchone()
print(f"Top earner: {top_earner}")
# fetchmany: Get the next N rows
next_three = cursor.fetchmany(3)
print(f"Next 3: {next_three}")
# fetchall: Get all remaining rows
remaining = cursor.fetchall()
print(f"Remaining: {len(remaining)} rows")
conn.close()Iterating Over Results Efficiently
For large result sets, iterate directly over the cursor instead of loading everything into memory:
import sqlite3
conn = sqlite3.connect("myapp.db")
cursor = conn.cursor()
cursor.execute("SELECT name, salary FROM employees")
# Memory-efficient: processes one row at a time
for name, salary in cursor:
print(f"{name}: ${salary:,.0f}")
conn.close()fetchmany with Batch Processing
When processing millions of rows, fetchmany() in a loop gives you control over memory usage:
import sqlite3
conn = sqlite3.connect("large_data.db")
cursor = conn.cursor()
cursor.execute("SELECT * FROM sensor_readings")
batch_size = 1000
while True:
rows = cursor.fetchmany(batch_size)
if not rows:
break
# Process batch
for row in rows:
pass # your processing logic
conn.close()Advanced Queries
JOINs
import sqlite3
conn = sqlite3.connect("school.db")
conn.row_factory = sqlite3.Row
cursor = conn.cursor()
# INNER JOIN: Students with their enrolled courses
cursor.execute("""
SELECT s.name AS student, c.title AS course, e.grade
FROM enrollments e
INNER JOIN students s ON e.student_id = s.id
INNER JOIN courses c ON e.course_id = c.id
ORDER BY s.name, c.title
""")
for row in cursor.fetchall():
print(f"{row['student']} - {row['course']}: {row['grade'] or 'In Progress'}")
# LEFT JOIN: All students, even those not enrolled
cursor.execute("""
SELECT s.name, COUNT(e.id) AS course_count
FROM students s
LEFT JOIN enrollments e ON s.id = e.student_id
GROUP BY s.id
ORDER BY course_count DESC
""")
for row in cursor.fetchall():
print(f"{row['name']}: {row['course_count']} courses")
conn.close()Aggregation
import sqlite3
conn = sqlite3.connect("myapp.db")
cursor = conn.cursor()
# Department statistics
cursor.execute("""
SELECT
department,
COUNT(*) AS headcount,
ROUND(AVG(salary), 2) AS avg_salary,
MIN(salary) AS min_salary,
MAX(salary) AS max_salary,
SUM(salary) AS total_payroll
FROM employees
WHERE is_active = 1
GROUP BY department
HAVING COUNT(*) >= 2
ORDER BY avg_salary DESC
""")
print(f"{'Department':<15} {'Count':<8} {'Avg Salary':<12} {'Min':<10} {'Max':<10}")
print("-" * 55)
for row in cursor.fetchall():
dept, count, avg_sal, min_sal, max_sal, total = row
print(f"{dept:<15} {count:<8} ${avg_sal:<11,.0f} ${min_sal:<9,.0f} ${max_sal:<9,.0f}")
conn.close()Subqueries
import sqlite3
conn = sqlite3.connect("myapp.db")
cursor = conn.cursor()
# Employees earning above their department average
cursor.execute("""
SELECT name, department, salary
FROM employees e
WHERE salary > (
SELECT AVG(salary) FROM employees
WHERE department = e.department
)
ORDER BY department, salary DESC
""")
for name, dept, salary in cursor.fetchall():
print(f"{name} ({dept}): ${salary:,.0f}")
# Most recent hire in each department
cursor.execute("""
SELECT name, department, hire_date
FROM employees
WHERE (department, hire_date) IN (
SELECT department, MAX(hire_date)
FROM employees
GROUP BY department
)
""")
for row in cursor.fetchall():
print(row)
conn.close()Window Functions (SQLite 3.25+)
SQLite supports window functions for running totals, rankings, and other analytical queries:
import sqlite3
conn = sqlite3.connect("myapp.db")
cursor = conn.cursor()
# Rank employees by salary within each department
cursor.execute("""
SELECT
name,
department,
salary,
RANK() OVER (PARTITION BY department ORDER BY salary DESC) AS dept_rank,
RANK() OVER (ORDER BY salary DESC) AS overall_rank
FROM employees
WHERE is_active = 1
""")
for name, dept, salary, dept_rank, overall_rank in cursor.fetchall():
print(f"#{overall_rank} overall, #{dept_rank} in {dept}: {name} (${salary:,.0f})")
# Running total of payroll by hire date
cursor.execute("""
SELECT
name,
hire_date,
salary,
SUM(salary) OVER (ORDER BY hire_date) AS running_total
FROM employees
ORDER BY hire_date
""")
for name, date, salary, running in cursor.fetchall():
print(f"{date} | {name}: ${salary:,.0f} | Running total: ${running:,.0f}")
conn.close()SQLite with pandas
pandas has built-in SQLite support through read_sql() and to_sql(). This makes it easy to move data between DataFrames and SQLite databases.
Reading SQL Results into a DataFrame
import sqlite3
import pandas as pd
conn = sqlite3.connect("myapp.db")
# Read a SQL query into a DataFrame
df = pd.read_sql("SELECT * FROM employees WHERE is_active = 1", conn)
print(df.head())
print(df.describe())
# Parameterized query with pandas
df = pd.read_sql(
"SELECT * FROM employees WHERE department = ? AND salary > ?",
conn,
params=("Engineering", 90000)
)
# Read an entire table
df = pd.read_sql("SELECT * FROM employees", conn, index_col="id")
conn.close()Writing a DataFrame to SQLite
import sqlite3
import pandas as pd
# Create a sample DataFrame
df = pd.DataFrame({
"product": ["Laptop", "Phone", "Tablet", "Monitor", "Keyboard"],
"price": [999.99, 699.99, 449.99, 349.99, 79.99],
"stock": [50, 200, 75, 30, 500],
"category": ["Electronics", "Electronics", "Electronics", "Peripherals", "Peripherals"]
})
conn = sqlite3.connect("store.db")
# Write DataFrame to a new table
df.to_sql("products", conn, if_exists="replace", index=False)
# Append to an existing table
new_products = pd.DataFrame({
"product": ["Mouse", "Webcam"],
"price": [49.99, 89.99],
"stock": [300, 100],
"category": ["Peripherals", "Peripherals"]
})
new_products.to_sql("products", conn, if_exists="append", index=False)
# Verify
result = pd.read_sql("SELECT * FROM products", conn)
print(result)
conn.close()Round-Trip Workflow: CSV to SQLite to Analysis
A common workflow is loading data from CSV files (see pandas read_csv) into SQLite for SQL-based analysis, then exporting the results.
import sqlite3
import pandas as pd
# Step 1: Load CSV into SQLite
df = pd.read_csv("sales_data.csv")
conn = sqlite3.connect("analytics.db")
df.to_sql("sales", conn, if_exists="replace", index=False)
# Step 2: Run SQL analytics
summary = pd.read_sql("""
SELECT
region,
strftime('%Y-%m', sale_date) AS month,
COUNT(*) AS transactions,
SUM(amount) AS revenue,
AVG(amount) AS avg_transaction
FROM sales
GROUP BY region, month
ORDER BY month, revenue DESC
""", conn)
print(summary)
# Step 3: Export results
summary.to_csv("monthly_summary.csv", index=False)
conn.close()Once you have your query results in a DataFrame, you can visualize them directly using PyGWalker (opens in a new tab). PyGWalker turns any pandas DataFrame into an interactive visualization interface similar to Tableau, letting you drag and drop fields to create charts without writing plotting code:
import pygwalker as pyg
# Turn your SQL query results into an interactive visualization
walker = pyg.walk(summary)For an even smoother workflow, RunCell (opens in a new tab) provides an AI-powered Jupyter environment where you can write SQL queries, get AI-assisted debugging, and instantly visualize results -- all in one notebook.
Error Handling
The sqlite3 module defines several exception types. Catching specific exceptions leads to better error messages and recovery strategies.
import sqlite3
def safe_insert(db_path, name, email, salary):
"""Insert an employee with proper error handling."""
try:
conn = sqlite3.connect(db_path)
cursor = conn.cursor()
cursor.execute(
"INSERT INTO employees (name, email, salary, hire_date) VALUES (?, ?, ?, date('now'))",
(name, email, salary)
)
conn.commit()
return cursor.lastrowid
except sqlite3.IntegrityError as e:
# Unique constraint violated (duplicate email, NOT NULL violated, etc.)
print(f"Data integrity error: {e}")
return None
except sqlite3.OperationalError as e:
# Table doesn't exist, SQL syntax error, database locked, etc.
print(f"Operational error: {e}")
return None
except sqlite3.DatabaseError as e:
# Corrupted database, disk full, etc.
print(f"Database error: {e}")
return None
except sqlite3.ProgrammingError as e:
# Using a closed cursor, wrong number of parameters, etc.
print(f"Programming error: {e}")
return None
finally:
if conn:
conn.close()SQLite3 Exception Hierarchy
| Exception | Parent | Common Causes |
|---|---|---|
sqlite3.Warning | Exception | Non-fatal issues |
sqlite3.Error | Exception | Base class for all sqlite3 errors |
sqlite3.InterfaceError | Error | Misuse of the DB-API interface |
sqlite3.DatabaseError | Error | Database-related errors |
sqlite3.DataError | DatabaseError | Data processing issues |
sqlite3.OperationalError | DatabaseError | Database locked, table missing, SQL error |
sqlite3.IntegrityError | DatabaseError | UNIQUE, NOT NULL, FOREIGN KEY violations |
sqlite3.InternalError | DatabaseError | Internal sqlite3 module error |
sqlite3.ProgrammingError | DatabaseError | Incorrect API usage |
sqlite3.NotSupportedError | DatabaseError | Unsupported feature |
Performance Tips
Enable WAL Mode
Write-Ahead Logging (WAL) mode allows concurrent reads while writing and improves write performance:
import sqlite3
conn = sqlite3.connect("myapp.db")
conn.execute("PRAGMA journal_mode=WAL")
# Returns 'wal' if successfulWAL mode is especially useful when you have a reader (e.g., a web server) and a writer (e.g., a background job) accessing the same database.
Use executemany for Bulk Inserts
executemany is significantly faster than calling execute in a loop because it reduces Python-to-SQLite round trips:
import sqlite3
import time
conn = sqlite3.connect(":memory:")
conn.execute("CREATE TABLE numbers (value INTEGER)")
data = [(i,) for i in range(100_000)]
# Slow: individual inserts
start = time.perf_counter()
for d in data:
conn.execute("INSERT INTO numbers VALUES (?)", d)
conn.commit()
slow_time = time.perf_counter() - start
conn.execute("DELETE FROM numbers")
# Fast: executemany
start = time.perf_counter()
conn.executemany("INSERT INTO numbers VALUES (?)", data)
conn.commit()
fast_time = time.perf_counter() - start
print(f"Individual inserts: {slow_time:.2f}s")
print(f"executemany: {fast_time:.2f}s")
print(f"Speedup: {slow_time / fast_time:.1f}x")
conn.close()Create Indexes for Frequently Queried Columns
Indexes speed up SELECT queries dramatically at the cost of slightly slower writes and more disk space:
import sqlite3
conn = sqlite3.connect("myapp.db")
# Single column index
conn.execute("CREATE INDEX IF NOT EXISTS idx_employees_department ON employees(department)")
# Composite index (for queries that filter on both columns)
conn.execute("CREATE INDEX IF NOT EXISTS idx_employees_dept_salary ON employees(department, salary)")
# Unique index (also enforces uniqueness)
conn.execute("CREATE UNIQUE INDEX IF NOT EXISTS idx_employees_email ON employees(email)")
# Check existing indexes
cursor = conn.execute("SELECT name, sql FROM sqlite_master WHERE type='index'")
for name, sql in cursor.fetchall():
print(f"{name}: {sql}")
conn.close()Use EXPLAIN QUERY PLAN to Check Performance
import sqlite3
conn = sqlite3.connect("myapp.db")
# Check how SQLite executes a query
result = conn.execute("""
EXPLAIN QUERY PLAN
SELECT * FROM employees WHERE department = 'Engineering' AND salary > 90000
""").fetchall()
for row in result:
print(row)
# Output shows whether an index is used or a full table scan occurs
conn.close()Additional PRAGMAs for Performance
import sqlite3
conn = sqlite3.connect("myapp.db")
# Increase cache size (default is 2000 pages = ~8MB)
conn.execute("PRAGMA cache_size = -64000") # 64MB (negative = KB)
# Reduce disk syncs for speed (less durable but much faster)
conn.execute("PRAGMA synchronous = NORMAL") # Options: OFF, NORMAL, FULL (default)
# Store temp tables in memory
conn.execute("PRAGMA temp_store = MEMORY")
# Check database integrity
result = conn.execute("PRAGMA integrity_check").fetchone()
print(f"Integrity: {result[0]}") # Should print 'ok'
conn.close()Real-World Example: Task Manager CLI
Here is a complete task manager application that demonstrates all the concepts covered in this guide. It uses SQLite for persistent storage, supports priorities, tags, and due dates.
import sqlite3
import sys
from datetime import datetime, date
from contextlib import contextmanager
DB_PATH = "tasks.db"
@contextmanager
def get_db():
"""Get a database connection with Row factory and foreign keys enabled."""
conn = sqlite3.connect(DB_PATH)
conn.row_factory = sqlite3.Row
conn.execute("PRAGMA foreign_keys = ON")
conn.execute("PRAGMA journal_mode = WAL")
try:
yield conn
conn.commit()
except Exception:
conn.rollback()
raise
finally:
conn.close()
def init_db():
"""Create tables if they don't exist."""
with get_db() as conn:
conn.execute("""
CREATE TABLE IF NOT EXISTS tasks (
id INTEGER PRIMARY KEY AUTOINCREMENT,
title TEXT NOT NULL,
description TEXT DEFAULT '',
priority INTEGER DEFAULT 2 CHECK(priority BETWEEN 1 AND 4),
status TEXT DEFAULT 'todo' CHECK(status IN ('todo', 'in_progress', 'done')),
due_date TEXT,
created_at TEXT DEFAULT CURRENT_TIMESTAMP,
completed_at TEXT
)
""")
conn.execute("""
CREATE TABLE IF NOT EXISTS tags (
id INTEGER PRIMARY KEY AUTOINCREMENT,
name TEXT UNIQUE NOT NULL
)
""")
conn.execute("""
CREATE TABLE IF NOT EXISTS task_tags (
task_id INTEGER NOT NULL,
tag_id INTEGER NOT NULL,
PRIMARY KEY (task_id, tag_id),
FOREIGN KEY (task_id) REFERENCES tasks(id) ON DELETE CASCADE,
FOREIGN KEY (tag_id) REFERENCES tags(id) ON DELETE CASCADE
)
""")
conn.execute("CREATE INDEX IF NOT EXISTS idx_tasks_status ON tasks(status)")
conn.execute("CREATE INDEX IF NOT EXISTS idx_tasks_priority ON tasks(priority)")
conn.execute("CREATE INDEX IF NOT EXISTS idx_tasks_due ON tasks(due_date)")
def add_task(title, description="", priority=2, due_date=None, tags=None):
"""Add a new task with optional tags."""
with get_db() as conn:
cursor = conn.execute(
"INSERT INTO tasks (title, description, priority, due_date) VALUES (?, ?, ?, ?)",
(title, description, priority, due_date)
)
task_id = cursor.lastrowid
if tags:
for tag_name in tags:
conn.execute("INSERT OR IGNORE INTO tags (name) VALUES (?)", (tag_name,))
tag_id = conn.execute("SELECT id FROM tags WHERE name = ?", (tag_name,)).fetchone()["id"]
conn.execute("INSERT INTO task_tags (task_id, tag_id) VALUES (?, ?)", (task_id, tag_id))
print(f"Task #{task_id} created: {title}")
return task_id
def list_tasks(status=None, priority=None, tag=None):
"""List tasks with optional filters."""
with get_db() as conn:
conditions = []
params = []
if status:
conditions.append("t.status = ?")
params.append(status)
if priority:
conditions.append("t.priority = ?")
params.append(priority)
if tag:
conditions.append("t.id IN (SELECT task_id FROM task_tags tt JOIN tags tg ON tt.tag_id = tg.id WHERE tg.name = ?)")
params.append(tag)
query = """
SELECT t.id, t.title, t.priority, t.status, t.due_date,
GROUP_CONCAT(tg.name, ', ') AS tags
FROM tasks t
LEFT JOIN task_tags tt ON t.id = tt.task_id
LEFT JOIN tags tg ON tt.tag_id = tg.id
"""
if conditions:
query += " WHERE " + " AND ".join(conditions)
query += " GROUP BY t.id ORDER BY t.priority ASC, t.due_date ASC"
rows = conn.execute(query, params).fetchall()
priority_labels = {1: "URGENT", 2: "HIGH", 3: "MEDIUM", 4: "LOW"}
print(f"\n{'ID':<5} {'Priority':<10} {'Status':<13} {'Due':<12} {'Title':<30} {'Tags'}")
print("-" * 85)
for row in rows:
due = row["due_date"] or "—"
tags_str = row["tags"] or "—"
p_label = priority_labels.get(row["priority"], "?")
print(f"{row['id']:<5} {p_label:<10} {row['status']:<13} {due:<12} {row['title']:<30} {tags_str}")
print(f"\nTotal: {len(rows)} tasks")
def complete_task(task_id):
"""Mark a task as done."""
with get_db() as conn:
result = conn.execute(
"UPDATE tasks SET status = 'done', completed_at = ? WHERE id = ?",
(datetime.now().isoformat(), task_id)
)
if result.rowcount:
print(f"Task #{task_id} marked as done.")
else:
print(f"Task #{task_id} not found.")
def stats():
"""Show task statistics."""
with get_db() as conn:
row = conn.execute("""
SELECT
COUNT(*) AS total,
SUM(CASE WHEN status = 'todo' THEN 1 ELSE 0 END) AS todo,
SUM(CASE WHEN status = 'in_progress' THEN 1 ELSE 0 END) AS in_progress,
SUM(CASE WHEN status = 'done' THEN 1 ELSE 0 END) AS done,
SUM(CASE WHEN due_date < date('now') AND status != 'done' THEN 1 ELSE 0 END) AS overdue
FROM tasks
""").fetchone()
print(f"\nTask Statistics:")
print(f" Total: {row['total']}")
print(f" To Do: {row['todo']}")
print(f" In Progress: {row['in_progress']}")
print(f" Done: {row['done']}")
print(f" Overdue: {row['overdue']}")
# Initialize and demo
if __name__ == "__main__":
init_db()
# Add sample tasks
add_task("Design database schema", priority=1, due_date="2026-02-20", tags=["backend", "database"])
add_task("Write API endpoints", priority=2, due_date="2026-02-25", tags=["backend", "api"])
add_task("Create unit tests", priority=3, tags=["testing"])
add_task("Update documentation", priority=4, due_date="2026-03-01", tags=["docs"])
# List and stats
list_tasks()
stats()
complete_task(1)
list_tasks(status="done")SQLite vs PostgreSQL vs MySQL vs MongoDB
| Feature | SQLite | PostgreSQL | MySQL | MongoDB |
|---|---|---|---|---|
| Type | Embedded | Client-server | Client-server | Document store |
| Setup | Zero config | Install + configure | Install + configure | Install + configure |
| Storage | Single file | Server directory | Server directory | Server directory |
| Max DB size | 281 TB | Unlimited | 256 TB | Unlimited |
| Concurrent writes | Limited (file lock) | Excellent (MVCC) | Good (row locks) | Good (document locks) |
| SQL support | Most of SQL92 | Full SQL + extensions | Full SQL | MQL (not SQL) |
| Data types | 5 storage classes | 40+ types | 30+ types | BSON types |
| Full-text search | FTS5 extension | Built-in tsvector | Built-in FULLTEXT | Built-in text index |
| JSON support | JSON1 extension | Native JSONB | Native JSON | Native (it is JSON) |
| Replication | Not built-in | Streaming + logical | Primary-replica | Replica sets |
| Best for | Embedded, local, prototypes | Web apps, analytics | Web apps, CMS | Flexible schema, documents |
| Python library | sqlite3 (built-in) | psycopg2 | mysql-connector | pymongo |
| Hosting required | No | Yes | Yes | Yes |
| Cost to start | Free, zero overhead | Free, but need server | Free, but need server | Free, but need server |
The decision is straightforward: use SQLite when your application is the only process writing to the database. Use PostgreSQL or MySQL when you need concurrent multi-user writes, replication, or network access. Use MongoDB when your data is document-oriented and does not fit a relational schema well.
Frequently Asked Questions
Is SQLite suitable for production use?
Yes. SQLite is used in production by Android, iOS, all major web browsers, Airbus flight software, and countless desktop applications. It handles up to 281 terabytes and millions of rows. It is not suitable for high-concurrency write-heavy web applications with many simultaneous users, but for most other scenarios it works well.
How do I check which version of SQLite Python is using?
Use sqlite3.sqlite_version to check the SQLite library version and sqlite3.version for the Python module version. For example: import sqlite3; print(sqlite3.sqlite_version) might output 3.45.1.
Can multiple processes read the same SQLite database?
Yes. Multiple processes can read from the same SQLite database simultaneously. Write operations acquire an exclusive lock on the database file. With WAL mode enabled, readers do not block writers and writers do not block readers. Only one writer can operate at a time.
How do I backup a SQLite database safely?
Use the sqlite3 backup API: source.backup(dest). You can also safely copy the database file while no writes are in progress. Never copy the file while a write transaction is active, as this can corrupt the backup.
import sqlite3
source = sqlite3.connect("myapp.db")
backup = sqlite3.connect("myapp_backup.db")
source.backup(backup)
backup.close()
source.close()How do I store dates and times in SQLite?
SQLite does not have a native DATE or DATETIME type. Store dates as TEXT in ISO 8601 format ('2026-02-18' or '2026-02-18T14:30:00'). SQLite's built-in date functions (date(), time(), datetime(), strftime()) work with this format. Alternatively, store Unix timestamps as INTEGER values.
Does SQLite support encryption?
The standard open-source SQLite does not include encryption. SQLite Encryption Extension (SEE) is a paid commercial product. Free alternatives include SQLCipher (open source) and pysqlcipher3 for Python integration.
How do I prevent SQL injection in Python sqlite3?
Always use parameterized queries with ? or :name placeholders. Never construct SQL strings using f-strings, .format(), or % string formatting with user input. The sqlite3 module handles escaping and quoting automatically when you pass parameters separately.
Conclusion
Python's sqlite3 module gives you a full-featured relational database with zero setup. For local applications, prototypes, data analysis scripts, and testing, SQLite is hard to beat. The key patterns to remember: always use parameterized queries to prevent SQL injection, use context managers for clean connection handling, enable WAL mode for better concurrency, and use executemany for bulk operations.
For data analysis workflows, the combination of SQLite and pandas is powerful: load data with to_sql(), query it with read_sql(), and visualize results with PyGWalker (opens in a new tab). For structuring your database records in Python code, consider using dataclasses to create typed data models that map cleanly to your table rows. When your project outgrows SQLite's concurrency limits, switching to PostgreSQL usually requires minimal code changes since the DB-API 2.0 interface is consistent across database drivers.
Related Guides
- Pandas to_sql -- Write DataFrames directly to SQL databases
- Pandas read_csv -- Load CSV data for SQLite import workflows
- Python pathlib -- Platform-independent database file path handling
- Python dataclasses -- Type-safe data models for database records