-
Notifications
You must be signed in to change notification settings - Fork 10
Add understanding client database page #285
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
Open
bean1352
wants to merge
4
commits into
main
Choose a base branch
from
diagnose-client-database
base: main
Could not load branches
Branch not found: {{ refName }}
Loading
Could not load tags
Nothing to show
Loading
Are you sure you want to change the base?
Some commits from the old base branch may be removed from the timeline,
and old review comments may become outdated.
Open
Changes from all commits
Commits
Show all changes
4 commits
Select commit
Hold shift + click to select a range
c00ff5e
Add understanding client database page
bean1352 83633a7
Fixed formatting and capital letters in headings
bean1352 e76cd0c
Add instructions on how to also pull the .wal file on Android and iOS
bean1352 65e5432
Changed example android destination path
bean1352 File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
There are no files selected for viewing
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
165 changes: 165 additions & 0 deletions
165
usage/lifecycle-maintenance/client-database-diagnostics.mdx
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -0,0 +1,165 @@ | ||
| --- | ||
| title: "Understanding The SQLite Database" | ||
| description: "Guide for analyzing and understanding the local SQLite database" | ||
| --- | ||
|
|
||
| ## Get the SQLite file | ||
|
|
||
| <Note> | ||
| A SQLite database file can use any extension - .db, .sqlite, .sqlite3, etc. The extension doesn’t affect functionality; all contain the same SQLite format. We also recommend pulling the associated [Write-Ahead Log (WAL)](https://www.sqlite.org/wal.html) file (with the same name as the database plus the suffix `-wal`) to ensure no recent changes are lost. | ||
| </Note> | ||
|
|
||
| <Tabs> | ||
| <Tab title="Android"> | ||
| Ensure your emulator is running, then replace `com.package-name` with your application's package name and `your-db-name.sqlite` with your database file name. | ||
|
|
||
| ```shell | ||
| adb exec-out run-as com.package-name cat databases/your-db-name.sqlite > "your/local/path/your-db-name.sqlite" | ||
| adb exec-out run-as com.package-name cat databases/your-db-name.sqlite-wal > "your/local/path/your-db-name.sqlite-wal" | ||
| ``` | ||
|
|
||
| **Common database locations:** | ||
| - [React Native Quick SQLite](/client-sdk-references/react-native-and-expo#react-native-quick-sqlite-2): `/data/data/com.package-name/files/` | ||
| - [OP-SQLite](/client-sdk-references/react-native-and-expo#op-sqlite): `/data/data/com.package-name/databases/` | ||
|
|
||
| **Note:** If the database is in a different location, first find it with: | ||
| ```shell | ||
| adb shell run-as com.package-name find /data/data/com.package-name -name "your-db-name.sqlite" | ||
| ``` | ||
| </Tab> | ||
| <Tab title="iOS"> | ||
| Replace `your-db-name.sqlite` with your database file name and extension. | ||
| ```shell | ||
| find ~/Library/Developer/CoreSimulator/Devices -type f -name 'your-db-name.sqlite' | ||
| find ~/Library/Developer/CoreSimulator/Devices -type f -name 'your-db-name.sqlite-wal' | ||
| ``` | ||
|
|
||
| **Common database location:** | ||
| - App sandbox: `Library/Application Support/` | ||
| </Tab> | ||
| <Tab title="Web"> | ||
|
|
||
| <Warning> | ||
| Write-Ahead Log (WAL) file is not used in web environments. Browser-based SQLite implementations handle transactions differently. | ||
| </Warning> | ||
|
|
||
| Web applications use browser-based storage APIs. Database files are managed by the browser and not directly accessible via filesystem paths. | ||
|
|
||
| **Storage options:** | ||
| - **OPFS (Origin Private File System)**: Native filesystem API with better performance (Chrome 102+, Firefox 111+, Safari 17.2+) | ||
| - **IndexedDB**: A key-value storage API. Unlike OPFS, IndexedDB doesn't store complete database files - it stores data in a structured format that cannot be directly downloaded as a SQLite file. | ||
|
|
||
| <Note> | ||
| Run the JavaScript code in your browser's console (F12 → Console) while on your application's page. | ||
| </Note> | ||
|
|
||
| **Export database to your computer (OPFS only):** | ||
| ```javascript | ||
| // For OPFS | ||
| async function downloadDatabase() { | ||
| const root = await navigator.storage.getDirectory(); | ||
| const fileHandle = await root.getFileHandle('your-db-name.sqlite'); | ||
| const file = await fileHandle.getFile(); | ||
|
|
||
| // Download the file | ||
| const url = URL.createObjectURL(file); | ||
| const a = document.createElement('a'); | ||
| a.href = url; | ||
| a.download = 'your-db-name.sqlite'; | ||
| a.click(); | ||
| URL.revokeObjectURL(url); | ||
| } | ||
|
|
||
| downloadDatabase(); | ||
| ``` | ||
|
|
||
| **Browser DevTools (inspect only):** | ||
| - Chrome/Edge: `F12` → Application → Storage → IndexedDB or OPFS | ||
| - Firefox: `F12` → Storage → IndexedDB | ||
| - Safari: Develop → Show Web Inspector → Storage | ||
| </Tab> | ||
| </Tabs> | ||
|
|
||
| ## Inspecting the SQLite file | ||
|
|
||
| ### 1. Open your SQLite file | ||
|
|
||
| Use the `sqlite3` command-line tool or a GUI tool like [DB Browser for SQLite](https://sqlitebrowser.org/) to open your database file: | ||
| ```shell | ||
| sqlite3 your-db-name.sqlite | ||
| ``` | ||
|
|
||
| ### 2. Merge the WAL file | ||
|
|
||
| Temporary changes are stored in a separate [Write-Ahead Log (WAL)](https://www.sqlite.org/wal.html) `.wal` file. To measure the database size accurately, merge these changes into the main database: | ||
| ```sql | ||
| PRAGMA wal_checkpoint(TRUNCATE); | ||
| ``` | ||
|
|
||
| ### 3. Get storage statistics | ||
|
|
||
| Query the built-in `dbstat` virtual table to see how much space each table uses on disk: | ||
| ```sql | ||
| SELECT name, pgsize AS storage_size, payload AS data_size | ||
| FROM dbstat | ||
| WHERE aggregate = true; | ||
| ``` | ||
|
|
||
| This returns: | ||
| - `name`: Table name | ||
| - `storage_size`: Total storage used on disk (in bytes, including SQLite overhead) | ||
| - `payload`: Actual data size (in bytes) | ||
|
|
||
| <Note> | ||
| The `dbstat` table is automatically available in SQLite and provides low-level information about physical storage. Values represent on-disk usage including SQLite's internal structures (page headers, B-trees, indexes, free space), which is why they're larger than your logical data size. | ||
| </Note> | ||
|
|
||
| ## Understanding the size breakdown | ||
|
|
||
| PowerSync databases contain more data than just your application tables to support the sync functionality: | ||
|
|
||
| 1. **Application data**: Your synced data in `ps_data__<table>` tables | ||
| 2. **Operation log (`ps_oplog`)**: A complete copy of all synced data required for offline conflict resolution and sync | ||
| 3. **Indexes**: For efficient queries and lookups | ||
| 4. **PowerSync metadata**: System tables and views for managing sync state (see [Client Architecture](https://docs.powersync.com/architecture/client-architecture#schema)) | ||
| 5. **SQLite overhead**: Page structure, alignment, fragmentation, and internal bookkeeping | ||
|
|
||
| The difference between `storage_size` and `payload` in the `dbstat` results shows SQLite's storage overhead. The `ps_oplog` table will typically be one of the largest tables since it maintains a full copy of your synced data. | ||
|
|
||
| To see just the JSON data size in `ps_oplog` (excluding SQLite overhead), run: | ||
| ```sql | ||
| SELECT sum(length(data)) / 1024.0 / 1024.0 AS size_mb FROM ps_oplog; | ||
| ``` | ||
| This measures only the raw JSON payloads, which will be smaller than the on-disk storage reported by `dbstat`. | ||
|
|
||
| ## Reducing SQLite file size | ||
|
|
||
| ### VACUUM Command | ||
|
|
||
| The `VACUUM` command reclaims unused space in the database: | ||
|
|
||
| ```sql | ||
| VACUUM; | ||
| ``` | ||
|
|
||
| <Warning> | ||
| The `VACUUM` command requires enough free disk space to create a temporary copy of the database. Ensure sufficient space is available before running. | ||
| </Warning> | ||
|
|
||
| ### Increase page size | ||
bean1352 marked this conversation as resolved.
Show resolved
Hide resolved
|
||
|
|
||
| <Warning> | ||
| This may cause issues when using `IndexedDB` on web - it is not supported there, and could corrupt the database. | ||
| </Warning> | ||
|
|
||
| Increasing the page size from the default **4KB** to **16KB** can reduce storage overhead significantly. | ||
|
|
||
| **Trade-offs:** | ||
| - Reduces storage overhead substantially | ||
| - May increase overhead for many small writes | ||
|
|
||
| The page size must be set as one of the first `PRAGMA` statements after opening the database: | ||
|
|
||
| ```sql | ||
| PRAGMA page_size = 16384; | ||
| ``` | ||
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
@bean1352 in your experience are you comfortable that users will know they need to wrap this in a
db.execute()call, or should we point that out?great PR btw, very overdue!