···11-- Raw records from firehose/jetstream
22-- Core table for all AT Protocol records before denormalization
33---
44--- Append-only log using plain MergeTree - all versions preserved for audit/rollback.
55--- Query-time deduplication via ORDER BY + LIMIT or window functions.
66--- JSON column stores full record, extract fields only when needed for ORDER BY/WHERE/JOINs
7384CREATE TABLE IF NOT EXISTS raw_records (
95 -- Decomposed AT URI components (at://did/collection/rkey)
106 did String,
117 collection LowCardinality(String),
128 rkey String,
1313-1414- -- Content identifier from the record (content-addressed hash)
159 cid String,
1616-1710 -- Repository revision (TID) - monotonically increasing per DID, used for ordering
1811 rev String,
1919-2020- -- Full record as native JSON (schema-flexible, queryable with record.field.subfield)
2112 record JSON,
2222-2323- -- Operation: 'create', 'update', 'delete', 'cache' (fetched on-demand)
1313+ -- Operation: 'create', 'update', 'delete', ('cache' - fetched on-demand)
2414 operation LowCardinality(String),
2525-2626- -- Firehose sequence number (metadata only, not for ordering - can jump on relay restart)
1515+ -- Firehose sequence number
2716 seq UInt64,
2828-2917 -- Event timestamp from firehose
3018 event_time DateTime64(3),
3131-3232- -- When we indexed this record
1919+ -- When the database indexed this record
3320 indexed_at DateTime64(3) DEFAULT now64(3),
3434-3521 -- Validation state: 'unchecked', 'valid', 'invalid_rev', 'invalid_gap', 'invalid_account'
3636- -- Populated by async batch validation, not in hot path
3722 validation_state LowCardinality(String) DEFAULT 'unchecked',
3838-3923 -- Whether this came from live firehose (true) or backfill (false)
4040- -- Backfill events may not reflect current state until repo is fully synced
4124 is_live Bool DEFAULT true,
4242-4325 -- Materialized AT URI for convenience
4426 uri String MATERIALIZED concat('at://', did, '/', collection, '/', rkey),
4545-4627 -- Projection for fast delete lookups by (did, cid)
4747- -- Delete events include CID, so we can O(1) lookup the original record
4848- -- to know what to decrement (e.g., which notebook's like count)
4928 PROJECTION by_did_cid (
5029 SELECT * ORDER BY (did, cid)
5130 )
···55 -- The DID this identity event is about
66 did String,
7788- -- Handle (may be empty if cleared)
88+ -- Handle (may be empty)
99 handle String,
10101111 -- Sequence number from firehose
···11-- Account events from firehose (#account messages)
22--- Tracks account status changes: active, deactivated, deleted, suspended, takendown
3243CREATE TABLE IF NOT EXISTS raw_account_events (
54 -- The DID this account event is about
···22-- Tracks our position in the firehose stream for resumption after restart
3344CREATE TABLE IF NOT EXISTS firehose_cursor (
55- -- Consumer identifier (allows multiple consumers with different cursors)
65 consumer_id String,
7687 -- Last successfully processed sequence number
···11-- Per-account revision state tracking
22-- Maintains latest rev/cid per DID for dedup and gap detection
33---
44--- AggregatingMergeTree with incremental MV from raw_records
55--- Query with argMaxMerge/maxMerge to finalize aggregates
6374CREATE TABLE IF NOT EXISTS account_rev_state (
85 -- Account DID
···11--- Incremental MV: fires on each insert to raw_records, maintains aggregate state
22--- Must be created after both account_rev_state (target) and raw_records (source) exist
11+3243CREATE MATERIALIZED VIEW IF NOT EXISTS account_rev_state_mv TO account_rev_state AS
54SELECT
···11-- Auto-populate freed status from account events
22--- JOINs against handle_mappings to find current handle for the DID
33--- If no mapping exists yet, the JOIN fails silently (can't free unknown handles)
4253CREATE MATERIALIZED VIEW IF NOT EXISTS handle_mappings_from_account_mv TO handle_mappings AS
64SELECT
···11-- Weaver profile source table
22--- Populated by MV from raw_records, merged into profiles by refreshable MV
3243CREATE TABLE IF NOT EXISTS profiles_weaver (
54 did String,
66-77- -- Raw profile JSON
85 profile String,
96107 -- Extracted fields for coalescing
···33CREATE MATERIALIZED VIEW IF NOT EXISTS profiles_weaver_mv TO profiles_weaver AS
44SELECT
55 did,
66- toString(record) as profile,
66+ record as profile,
77 coalesce(record.displayName, '') as display_name,
88 coalesce(record.description, '') as description,
99 coalesce(record.avatar.ref.`$link`, '') as avatar_cid,
···11-- Bluesky profile source table
22--- Populated by MV from raw_records, merged into profiles by refreshable MV
3243CREATE TABLE IF NOT EXISTS profiles_bsky (
54 did String,
6577- -- Raw profile JSON
86 profile String,
97108 -- Extracted fields for coalescing
···33CREATE MATERIALIZED VIEW IF NOT EXISTS profiles_bsky_mv TO profiles_bsky AS
44SELECT
55 did,
66- toString(record) as profile,
66+ record as profile,
77 coalesce(record.displayName, '') as display_name,
88 coalesce(record.description, '') as description,
99 coalesce(record.avatar.ref.`$link`, '') as avatar_cid,
···11-- Unified profiles view
22--- Refreshable MV that merges weaver + bsky profiles with handle resolution
33--- Queries are pure reads, no merge computation needed
44-52CREATE MATERIALIZED VIEW IF NOT EXISTS profiles
63REFRESH EVERY 1 MINUTE
74ENGINE = ReplacingMergeTree(indexed_at)
···96AS SELECT
107 if(w.did != '', w.did, b.did) as did,
1181212- -- Handle from handle_mappings (empty if not resolved yet)
139 coalesce(h.handle, '') as handle,
14101511 -- Raw profiles per source
···11--- Notebook engagement counts
22--- Updated by MVs from likes, bookmarks, subscriptions (added later with graph tables)
33--- Joined with notebooks at query time
11+-- Notebook engagement counts table stub
4253CREATE TABLE IF NOT EXISTS notebook_counts (
64 did String,
···11--- Entry engagement counts
22--- Updated by MVs from likes, bookmarks (added later with graph tables)
33--- Joined with entries at query time
11+-- Entry engagement counts table stub
4253CREATE TABLE IF NOT EXISTS entry_counts (
64 did String,
···11-- Draft stub records
22--- Anchors for unpublished content, enables draft discovery via queries
3243CREATE TABLE IF NOT EXISTS drafts (
54 -- Identity
···11-- Notebook entries mapping (denormalized for reverse lookup)
22-- Maps entries to the notebooks that contain them
33--- Enables reverse lookup: find notebooks containing an entry
4354CREATE TABLE IF NOT EXISTS notebook_entries (
65 -- Entry being referenced
···11-- Populate notebook_entries from notebooks
22--- Extracts entry references from the entryList in notebook records
33--- Incremental MV: triggers on INSERT to notebooks, writes to notebook_entries
4253CREATE MATERIALIZED VIEW IF NOT EXISTS notebook_entries_mv
64TO notebook_entries
75AS
86SELECT
99- -- Parse entry URI to extract did and rkey
1010- -- URI format: at://did:plc:xxx/sh.weaver.notebook.entry/rkey
1111- -- assumeNotNull is safe here because WHERE filters guarantee non-null
127 assumeNotNull(extract(entry_uri, 'at://([^/]+)/')) as entry_did,
138 assumeNotNull(extract(entry_uri, '/sh\\.weaver\\.notebook\\.entry/([^/]+)$')) as entry_rkey,
149
···133133 Ok(row)
134134 }
135135136136- /// List entries for a notebook's author (did).
136136+ /// List entries for a specific notebook, ordered by position in the notebook.
137137 ///
138138- /// Note: This is a simplified version. The full implementation would
139139- /// need to join with notebook's entryList to get proper ordering.
140140- /// For now, we just list entries by the same author, ordered by rkey (notebook order).
138138+ /// Uses notebook_entries table to get entries that belong to this notebook.
141139 pub async fn list_notebook_entries(
142140 &self,
143143- did: &str,
141141+ notebook_did: &str,
142142+ notebook_rkey: &str,
144143 limit: u32,
145145- cursor: Option<&str>,
144144+ cursor: Option<u32>,
146145 ) -> Result<Vec<EntryRow>, IndexError> {
147147- // Note: rkey ordering is intentional here - it's the notebook's entry order
148148- let query = if cursor.is_some() {
149149- r#"
150150- SELECT did, rkey, cid, uri, title, path, tags, author_dids, created_at, indexed_at, record
151151- FROM (
152152- SELECT did, rkey, cid, uri, title, path, tags, author_dids, created_at, updated_at, indexed_at, record,
153153- ROW_NUMBER() OVER (PARTITION BY rkey ORDER BY updated_at DESC) as rn
154154- FROM entries FINAL
155155- WHERE did = ?
156156- AND deleted_at = toDateTime64(0, 3)
157157- AND rkey > ?
158158- )
159159- WHERE rn = 1
160160- ORDER BY rkey ASC
161161- LIMIT ?
162162- "#
163163- } else {
164164- r#"
165165- SELECT did, rkey, cid, uri, title, path, tags, author_dids, created_at, indexed_at, record
166166- FROM (
167167- SELECT did, rkey, cid, uri, title, path, tags, author_dids, created_at, updated_at, indexed_at, record,
168168- ROW_NUMBER() OVER (PARTITION BY rkey ORDER BY updated_at DESC) as rn
169169- FROM entries FINAL
170170- WHERE did = ?
171171- AND deleted_at = toDateTime64(0, 3)
172172- )
173173- WHERE rn = 1
174174- ORDER BY rkey ASC
175175- LIMIT ?
176176- "#
177177- };
146146+ let query = r#"
147147+ SELECT
148148+ e.did AS did,
149149+ e.rkey AS rkey,
150150+ e.cid AS cid,
151151+ e.uri AS uri,
152152+ e.title AS title,
153153+ e.path AS path,
154154+ e.tags AS tags,
155155+ e.author_dids AS author_dids,
156156+ e.created_at AS created_at,
157157+ e.indexed_at AS indexed_at,
158158+ e.record AS record
159159+ FROM notebook_entries ne FINAL
160160+ INNER JOIN entries e ON
161161+ e.did = ne.entry_did
162162+ AND e.rkey = ne.entry_rkey
163163+ AND e.deleted_at = toDateTime64(0, 3)
164164+ WHERE ne.notebook_did = ?
165165+ AND ne.notebook_rkey = ?
166166+ AND ne.position > ?
167167+ ORDER BY ne.position ASC
168168+ LIMIT ?
169169+ "#;
178170179179- let mut q = self.inner().query(query).bind(did);
180180-181181- if let Some(c) = cursor {
182182- q = q.bind(c);
183183- }
171171+ let cursor_val = cursor.unwrap_or(0);
184172185185- let rows =
186186- q.bind(limit)
187187- .fetch_all::<EntryRow>()
188188- .await
189189- .map_err(|e| ClickHouseError::Query {
190190- message: "failed to list notebook entries".into(),
191191- source: e,
192192- })?;
173173+ let rows = self
174174+ .inner()
175175+ .query(query)
176176+ .bind(notebook_did)
177177+ .bind(notebook_rkey)
178178+ .bind(cursor_val)
179179+ .bind(limit)
180180+ .fetch_all::<EntryRow>()
181181+ .await
182182+ .map_err(|e| ClickHouseError::Query {
183183+ message: "failed to list notebook entries".into(),
184184+ source: e,
185185+ })?;
193186194187 Ok(rows)
195188 }
···1212use self::repo::XrpcErrorResponse;
13131414pub mod actor;
1515+pub mod bsky;
1516pub mod collab;
1617pub mod edit;
1818+pub mod identity;
1719pub mod notebook;
1820pub mod repo;
1921
+27-29
crates/weaver-index/src/endpoints/notebook.rs
···4545 let did_str = did.as_str();
4646 let name = args.name.as_ref();
47474848- // Fetch notebook and entries in parallel - both just need the DID
4948 let limit = args.entry_limit.unwrap_or(50).clamp(1, 100) as u32;
5050- let cursor = args.entry_cursor.as_deref();
4949+ let cursor: Option<u32> = args
5050+ .entry_cursor
5151+ .as_deref()
5252+ .and_then(|c| c.parse().ok());
51535252- let (notebook_result, entries_result) = tokio::try_join!(
5353- async {
5454- state
5555- .clickhouse
5656- .resolve_notebook(did_str, name)
5757- .await
5858- .map_err(|e| {
5959- tracing::error!("Failed to resolve notebook: {}", e);
6060- XrpcErrorResponse::internal_error("Database query failed")
6161- })
6262- },
6363- async {
6464- state
6565- .clickhouse
6666- .list_notebook_entries(did_str, limit + 1, cursor)
6767- .await
6868- .map_err(|e| {
6969- tracing::error!("Failed to list entries: {}", e);
7070- XrpcErrorResponse::internal_error("Database query failed")
7171- })
7272- }
7373- )?;
5454+ // Fetch notebook first to get its rkey
5555+ let notebook_row = state
5656+ .clickhouse
5757+ .resolve_notebook(did_str, name)
5858+ .await
5959+ .map_err(|e| {
6060+ tracing::error!("Failed to resolve notebook: {}", e);
6161+ XrpcErrorResponse::internal_error("Database query failed")
6262+ })?
6363+ .ok_or_else(|| XrpcErrorResponse::not_found("Notebook not found"))?;
74647575- let notebook_row =
7676- notebook_result.ok_or_else(|| XrpcErrorResponse::not_found("Notebook not found"))?;
7777- let entry_rows = entries_result;
6565+ // Now fetch entries using notebook's rkey
6666+ let entry_rows = state
6767+ .clickhouse
6868+ .list_notebook_entries(did_str, ¬ebook_row.rkey, limit + 1, cursor)
6969+ .await
7070+ .map_err(|e| {
7171+ tracing::error!("Failed to list entries: {}", e);
7272+ XrpcErrorResponse::internal_error("Database query failed")
7373+ })?;
78747975 // Fetch notebook contributors (evidence-based)
8076 let notebook_contributors = state
···183179 entries.push(book_entry);
184180 }
185181186186- // Build cursor for pagination
182182+ // Build cursor for pagination (position-based)
187183 let next_cursor = if has_more {
188188- entry_rows.last().map(|e| e.rkey.to_string().into())
184184+ // Position = cursor offset + number of entries returned
185185+ let last_position = cursor.unwrap_or(0) + entry_rows.len() as u32;
186186+ Some(last_position.to_string().into())
189187 } else {
190188 None
191189 };
···11+If you've been to this site before, you maybe noticed it loaded a fair bit more quickly this time. That's not really because the web server creating this HTML got a whole lot better. It did require some refactoring, but it was mostly in the vein of taking some code and adding new code that did the same thing gated behind a cargo feature. This did, however, have the side effect of, in the final binary, replacing functions that are literally hundreds of lines, that in turn call functions that may also be hundreds of lines, making several cascading network requests, with functions that look like this, which make by and large a single network request and return exactly what is required.
22+33+```rust
44+#[cfg(feature = "use-index")]
55+fn fetch_entry_view(
66+ &self,
77+ entry_ref: &StrongRef<'_>,
88+) -> impl Future<Output = Result<EntryView<'static>, WeaverError>>
99+where
1010+ Self: Sized,
1111+{
1212+ async move {
1313+ use weaver_api::sh_weaver::notebook::get_entry::GetEntry;
1414+1515+ let resp = self
1616+ .send(GetEntry::new().uri(entry_ref.uri.clone()).build())
1717+ .await
1818+ .map_err(|e| AgentError::from(ClientError::from(e)))?;
1919+2020+ let output = resp.into_output().map_err(|e| {
2121+ AgentError::xrpc(e.into))
2222+ })?;
2323+2424+ Ok(output.value.into_static())
2525+ }
2626+}
2727+```
2828+2929+Of course the reason is that I finally got round to building the Weaver AppView. I'm going to be calling mine the Index, because Weaver is about writing and I think "AppView" as a term kind of sucks and "index" is much more elegant, on top of being a good descriptor of what the big backend service now powering Weaver does. ![[at://did:plc:ragtjsm2j2vknwkz3zp4oxrd/app.bsky.feed.post/3lyucxfxq622w]]
3030+For the uninitiated, because I expect at least some people reading this aren't big into AT Protocol development, an AppView is an instance of the kind of big backend service that Bluesky PBLLC runs which powers essentially every Bluesky client, with a few notable exceptions, such as [Red Dwarf](https://reddwarf.app/), and (partially, eventually more completely) [Blacksky](https://blacksky.community/). It listens to the [Firehose](https://bsky.network/) [event stream](https://atproto.com/specs/event-stream) from the main Bluesky Relay and analyzes the data which comes through that pertains to Bluesky, producing your timeline feeds, figuring out who follows you, who you block and who blocks you (and filtering them out of your view of the app), how many people liked your last post, and so on. Because the records in your PDS (and those of all the other people on Bluesky) need context and relationship and so on to give them meaning, and then that context can be passed along to you without your app having to go collect it all. ![[at://did:plc:uu5axsmbm2or2dngy4gwchec/app.bsky.feed.post/3lsc2tzfsys2f]]
3131+It's a very normal backend with some weird constraints because of the protocol, and in it's practice the thing that separates the day-to-day Bluesky experience from the Mastodon experience the most. It's also by far the most centralising force in the network, because it also does moderation, and because it's quite expensive to run. A full index of all Bluesky activity takes a lot of storage (futur's Zeppelin experiment detailed above took about 16 terabytes of storage using PostgreSQL for the database and cost $200/month to run), and then it takes that much more computing power to calculate all the relationships between the data on the fly as new events come in and then serve personalized versions to everyone that uses it.
3232+3333+It's not the only AppView out there, most atproto apps have something like this. Tangled, Streamplace, Leaflet, and so on all have substantial backends. Some (like Tangled) actually combine the front end you interact with and the AppView into a single service. But in general these are big, complicated persistent services you have to backfill from existing data to bootstrap, and they really strongly shape your app, whether they're literally part of the same executable or hosted on the same server or not. And when I started building Weaver in earnest, not only did I still have a few big unanswered questions about how I wanted Weaver to work, how it needed to work, I also didn't want to fundamentally tie it to some big server, create this centralising force. I wanted it to be possible for someone else to run it without being dependent on me personally, ideally possible even if all they had access to was a static site host like GitHub Pages or a browser runtime platform like Cloudflare Workers, so long as someone somewhere was running a couple of generic services. I wanted to be able to distribute the fullstack server version as basically just an executable in a directory of files with no other dependencies, which could easily be run in any container hosting environment with zero persistent storage required. Hell, you could technically serve it as a blob or series of blobs from your PDS with the right entry point if I did my job right.
3434+3535+I succeeded.
3636+3737+Well, I don't know if you can serve `weaver-app` purely via `com.atproto.sync.getBlob` request, but it doesn't need much.
3838+## Constellation
3939+![[at://did:plc:ttdrpj45ibqunmfhdsb4zdwq/app.bsky.feed.post/3m6pckslkt222]] Ana's leaflet does a good job of explaining more or less how Weaver worked up until now. It used direct requests to personal data servers (mostly mine) as well as many calls to [Constellation](https://constellation.microcosm.blue/) and [Slingshot](https://slingshot.microcosm.blue/), and some even to [UFOs](https://ufos.microcosm.blue/), plus a couple of judicious calls to the Bluesky AppView for profiles and post embeds. ![[at://did:plc:hdhoaan3xa3jiuq4fg4mefid/app.bsky.feed.post/3m5jzclsvpc2c]]
4040+The three things linked above are generic services that provide back-links, a record cache, and a running feed of the most recent instances of all lexicons on the network, respectively. That's more than enough to build an app with, though it's not always easy. For some things it can be pretty straightforward. Constellation can tell you what notebooks an entry is in. It can tell you which edit history records are related to this notebook entry. For single-layer relationships it's straightforward. However you then have to also fetch the records individually, because it doesn't provide you the records, just the URIs you need to find them. Slingshot doesn't currently have an endpoint that will batch fetch a list of URIs for you. And the PDS only has endpoints like [`com.atproto.repo.listRecords`](https://docs.bsky.app/docs/api/com-atproto-repo-list-records), which gives you a paginated list of all records of a specific type, but doesn't let you narrow that down easily, so you have to page through until you find what you wanted.
4141+4242+This wouldn't be too bad if I was fine with almost everything after the hostname in my web URLs being gobbledegook record keys, but I wanted people to be able to link within a notebook like they normally would if they were linking within an Obsidian Vault, by name or by path, something human-readable. So some queries became the good old N+1 requests, because I had to list a lot of records and fetch them until I could find the one that matched. Or worse still, particularly once I introduce collaboration and draft syncing to the editor. Loading a draft of an entry with a lot of edit history could take 100 or more requests, to check permissions, find all the edit records, figure out which ones mattered, publish the collaboration session record, check for collaborators, and so on. It was pretty slow going, particularly when one could not pre-fetch and cache and generate everything server-side on a real CPU rather than in a browser after downloading a nice chunk of WebAssembly code. My profile page [alpha.weaver.sh/nonbinary.computer](https://alpha.weaver.sh/nonbinary.computer) often took quite some time to load due to a frustrating quirk of Dioxus, the Rust web framework I've used for the front-end, which prevented server-side rendering from waiting until everything important had been fetched to render the complete page on that specific route, forcing me to load it client-side.
4343+4444+Some stuff is just complicated to graph out, to find and pull all the relevant data together in order, and some connections aren't the kinds of things you can graph generically. For example, in order to work without any sort of service that has access to indefinite authenticated sessions of more than one person at once, Weaver handles collaborative writing and publishing by having each collaborator write to their own repository and publish there, and then, when the published version is requested, figuring out which version of an entry or notebook is most up-to-date, and displaying that one. It matches by record key across more than one repository, determined at request time by the state of multiple other records in those users' repositories.
4545+4646+# Shape of Data
4747+All of that being said, this was still the correct route, particularly for me. Because not only does this provide a powerful fallback mode, built-in protection against me going AWOL, it was critical in the design process of the index. My friend Ollie, when talking about database and API design, always says that, regardless of the specific technology you use, you need to structure your data based on how you need to query into it. Whatever interface you put in front of it, be it GraphQL, SQL, gRPC, XRPC, server functions, AJAX, literally any way that you can have the part of your app that people interact with pull the specific data they want from where it's stored, how well that performs, how many cycles your server or client spends collecting it, sorting it, or waiting on it, how much memory it takes, how much bandwidth it takes, depends on how that data is shaped, and you, when you are designing your app and all the services that go into it, get to choose that shape.
4848+4949+Bluesky developers have said that hydrating blocks, mutes, and labels and applying the appropriate ones to the feed content based on the preferences of the user takes quite a bit of compute at scale, and that even the seemingly simple [Following feed](https://jazco.dev/2025/02/19/imperfection/), which is mostly a reverse-chronological feed of posts by people you follow explicitly (plus a few simple rules), is remarkably resource-intensive to produce for them. The extremely clever [string interning](https://jazco.dev/2025/09/26/interning/) and [bitmap tricks](https://jazco.dev/2024/04/20/roaring-bitmaps/) implemented by a brilliant engineer during their time at Bluesky are all oriented toward figuring out the most efficient way to structure the data to make the desired query emerge naturally from it. 
5050+5151+It's intuitive that this matters a lot when you use something like RocksDB, or FoundationDB, or Redis, which are fundamentally key-value stores. What your key contains there determines almost everything about how easy it is to find and manipulate the values you want. Fig and I have had some struggles getting a backup of their Constellation service running in real-time and keeping up with Jetstream on my home server, because the only storage on said home server with enough free space for Constellation's full index is a ZFS pool that's primarily hard-drive based, and the way the Constellation RocksDB backend storage is structured makes processing delete events extremely expensive on a hard drive where seek times are nontrivial. On a Pi 4 with an SSD, it runs just fine. ![[at://did:plc:44ybard66vv44zksje25o7dz/app.bsky.feed.post/3m7e3hnyh5c2u]]
5252+But it's a problem for every database. Custom feed builder service [graze.social](https://graze.social/) ran into difficulties with Postgres early on in their development, as they rapidly gained popularity. They ended up using the same database I did, Clickhouse, for many of the same reasons. ![[at://did:plc:i6y3jdklpvkjvynvsrnqfdoq/app.bsky.feed.post/3m7ecmqcwys23]]
5353+And while thankfully I don't think that a platform oriented around long-form written content will ever have the kinds of following timeline graph write amplification problems Bluesky has dealt with, even if it becomes successful beyond my wildest dreams, there are definitely going to be areas where latency matters a ton and the workload is very write-heavy, like real-time collaboration, particularly if a large number of people work on a document simultaneously, even while the vast majority of requests will primarily be reading data out.
5454+5555+One reason why the edit records for Weaver have three link fields (and may get more!), even though it may seem a bit redundant, is precisely because those links make it easy to graph the relationships between them, to trace a tree of edits backward to the root, while also allowing direct access and a direct relationship to the root snapshot and the thing it's associated with.
5656+5757+In contrast, notebook entry records lack links to other parts of the notebook in and of themselves because calculating them would be challenging, and updating one entry would require not just updating the entry itself and notebook it's in, but also neighbouring entries in said notebook. With the shape of collaborative publishing in Weaver, that would result in up to 4 writes to the PDS when you publish an entry, in addition to any blob uploads. And trying to link the other way in edit history (root to edit head) is similarly challenging.
5858+5959+I anticipated some of these. but others emerged only because I ran into them while building the web app. I've had to manually fix up records more than once because I made breaking changes to my lexicons after discovering I really wanted X piece of metadata or cross-linkage. If I'd built the index first or alongside—particularly if the index remained a separate service from the web app as I intended it to, to keep the web app simple—it would likely have constrained my choices and potentially cut off certain solutions, due to the time it takes to dump the database and re-run backfill even at a very small scale. Building a big chunk of the front end first told me exactly what the index needed to provide easy access to.
6060+# ClickHAUS
6161+So what does Weaver's index look like? Well it starts with either the firehose or the new Tap sync tool. The index ingests from either over a WebSocket connection, does a bit of processing (less is required when ingesting from Tap, and that's currently what I've deployed) and then dumps them in the Clickhouse database. I chose it as the primary index database on recommendation from a friend, and after doing a lot of reading. It fits atproto data well, as Graze found. Because it isolates concurrent inserts and selects so that you can just dump data in, while it cleans things up asynchronously after, it does wonderfully when you have a single major input point or a set of them to dump into that fans out, which you can then transform and then read from.
6262+6363+I will not claim that the tables you can find in the weaver repository are especially **good** database design overall, but they work, and we'll see how they scale. This is one of three main input tables. One for record writes, one for identity events, and one for account events.
6464+```SQL
6565+CREATE TABLE IF NOT EXISTS raw_records (
6666+ did String,
6767+ collection LowCardinality(String),
6868+ rkey String,
6969+ cid String,
7070+ -- Repository revision (TID)
7171+ rev String,
7272+ record JSON,
7373+ -- Operation: 'create', 'update', 'delete', 'cache' (fetched on-demand)
7474+ operation LowCardinality(String),
7575+ -- Firehose sequence number
7676+ seq UInt64,
7777+ -- Event timestamp from firehose
7878+ event_time DateTime64(3),
7979+ -- When the database indexed this record
8080+ indexed_at DateTime64(3) DEFAULT now64(3),
8181+ -- Validation state: 'unchecked', 'valid', 'invalid_rev', 'invalid_gap', 'invalid_account'
8282+ validation_state LowCardinality(String) DEFAULT 'unchecked',
8383+ -- Whether this came from live firehose (true) or backfill (false)
8484+ is_live Bool DEFAULT true,
8585+ -- Materialized AT URI for convenience
8686+ uri String MATERIALIZED concat('at://', did, '/', collection, '/', rkey),
8787+ -- Projection for fast delete lookups by (did, cid)
8888+ PROJECTION by_did_cid (
8989+ SELECT * ORDER BY (did, cid)
9090+ )
9191+)
9292+ENGINE = MergeTree()
9393+ORDER BY (collection, did, rkey, event_time, indexed_at);
9494+```
9595+From here we fan out into a cascading series of materialized views and other specialised tables. These break out the different record types, calculate metadata, and pull critical fields out of the record JSON for easier querying. Clickhouse's wild-ass compression means we're not too badly off replicating data on disk this way. Seriously, their JSON type ends up being the same size as a CBOR BLOB on disk in my testing, though it *does* have some quirks, as I discovered when I read back Datetime fields and got...not the format I put in. Thankfully there's a config setting for that. We also build out the list of who contributed to a published entry and determine the canonical record for it, so that fetching a fully hydrated entry with all contributor profiles only takes a couple of `SELECT` queries that themselves avoid performing extensive table scans due to reasonable choices of `ORDER BY` fields in the denormalized tables they query. And then I can do quirky things like power a profile fetch endpoint that will provide either a Weaver or a Bluesky profile, while also unifying fields so that we can easily get at the critical stuff in common. This is a relatively expensive calculation, but people thankfully don't edit their profiles that often, and this is why we don't keep the stats in the same table.
9696+9797+However, this is ***also*** why Clickhouse will not be the only database used in the index.
9898+9999+# Why is it always SQLite?
100100+When it comes to things like real-time collaboration sessions with almost keystroke-level cursor tracking and rapid per-user writeback/readback, where latency matters and we can't wait around for the merge cycle to produce the right state, *don't* work well in Clickhouse. But they sure do in SQLite!
101101+102102+If there's one thing the AT Protocol developer community loves more than base32-encoded timestamps it's SQLite. In fairness, we're in good company, the whole world loves SQLite. It's a good fucking embedded database and very hard to beat for write or read performance so long as you're not trying to hit it massively concurrently. Of course, that concurrency limitation does end up mattering as you scale. And here we take a cue from the Typescript PDS implementation and discover the magic of buying, well, a lot more than two of them, and of using the filesystem like a hierarchical key-value store.
103103+104104+<iframe width="560" height="315" src="https://www.youtube.com/embed/CZs-YcmxyUw?si=bd3GmSxMVQGdqHAR" title="YouTube video player" frameborder="0" allow="accelerometer; autoplay; clipboard-write; encrypted-media; gyroscope; picture-in-picture; web-share" referrerpolicy="strict-origin-when-cross-origin" allowfullscreen></iframe>
105105+106106+This part of the data backend is still *very* much a work-in-progress and isn't used yet in the deployed version, but I did want to discuss the architecture. Unlike the PDS, we don't divide primarily by DID, instead we shard by resource, designated by collection and record key.
107107+108108+```rust
109109+pub struct ShardKey {
110110+ pub collection: SmolStr,
111111+ pub rkey: SmolStr,
112112+}
113113+114114+impl ShardKey {
115115+...
116116+ /// Directory path: {base}/{hash(collection,rkey)[0..2]}/{rkey}/
117117+ fn dir_path(&self, base: &Path) -> PathBuf {
118118+ base.join(self.hash_prefix()).join(self.rkey.as_str())
119119+ }
120120+...
121121+}
122122+/// A single SQLite shard for a resource
123123+pub struct SqliteShard {
124124+ conn: Mutex<Connection>,
125125+ path: PathBuf,
126126+ last_accessed: Mutex<Instant>,
127127+}
128128+/// Routes resources to their SQLite shards
129129+pub struct ShardRouter {
130130+ base_path: PathBuf,
131131+ shards: DashMap<ShardKey, std::sync::Arc<SqliteShard>>,
132132+}
133133+```
134134+135135+The hash of the shard key plus the record key gives us the directory where we put the database file for this resource. Ultimately this may be moved out of the main index off onto something more comparable to the Tangled knot server or Streamplace nodes, depending on what constraints we run into if things go exceptionally well, but for now it lives as part of the index. In there we can tee off raw events from the incoming firehose and then transform them into the correct forms in memory, optionally persisted to disk, alongside Clickhouse and probably, for the specific things we want it for with a local scope, faster.
136136+137137+And direct communication, either by using something like oatproxy to swap the auth relationships around a bit (currently the index is accessed via service proxying through the PDS when authenticated) or via an iroh channel from the client, gets stuff there without having to wait for the relay to pick it up and fan it out to us, which then means that users can read their own writes very effectively. The handler hits the relevant SQLite shard if present and Clickhouse in parallel, merging the data to provide the most up-to-date form. For real-time collaboration this is critical. The current `iroh-gossip` implementation works well and requires only a generic iroh relay, but it runs into the problem every gossip protocol runs into the more concurrent users you have.
138138+139139+The exact method of authentication of that side-channel is by far the largest remaining unanswered question about Weaver right now, aside from "Will anyone (else) use it?"
140140+141141+If people have ideas, I'm all ears.
142142+143143+I hope you found this interesting. I enjoyed writing it out.