2021-06-27 13:31:30 -07:00
PRAGMA foreign_keys = on ;
2024-02-24 16:45:08 -08:00
-- Users
-- -----
2021-06-27 13:31:30 -07:00
create table users ( rowid integer primary key ,
2021-07-24 21:52:39 -07:00
id integer unique not null check ( typeof ( id ) = ' integer ' ) ,
2021-06-27 13:31:30 -07:00
display_name text not null ,
2024-09-17 18:30:11 -07:00
handle text not null ,
2021-06-27 13:31:30 -07:00
bio text ,
2021-07-24 21:52:39 -07:00
following_count integer ,
followers_count integer ,
2021-06-27 13:31:30 -07:00
location text ,
website text ,
join_date integer ,
is_private boolean default 0 ,
is_verified boolean default 0 ,
2022-01-07 12:38:56 -05:00
is_banned boolean default 0 ,
2023-08-22 20:07:32 -03:00
is_deleted boolean default 0 ,
2021-06-27 13:31:30 -07:00
profile_image_url text ,
2021-08-10 20:51:42 -07:00
profile_image_local_path text ,
2021-06-27 13:31:30 -07:00
banner_image_url text ,
2021-08-10 20:51:42 -07:00
banner_image_local_path text ,
2021-07-25 15:42:43 -07:00
pinned_tweet_id integer check ( typeof ( pinned_tweet_id ) = ' integer ' or pinned_tweet_id = ' ' ) ,
2022-02-26 15:58:30 -08:00
is_followed boolean default 0 ,
2022-02-26 22:09:27 -08:00
is_id_fake boolean default 0 ,
2021-07-25 15:42:43 -07:00
is_content_downloaded boolean default 0
2021-11-06 13:37:46 -07:00
) ;
2024-09-17 18:30:11 -07:00
create unique index index_active_users_handle_unique on users ( handle ) where is_banned = 0 and is_deleted = 0 ;
create view users_by_handle as
with active_users as (
select * from users where is_banned = 0 and is_deleted = 0
) , inactive_users as (
select * from users where is_banned = 1 or is_deleted = 1
) , inactive_users_with_no_shadowing_active_user as (
select * from inactive_users where not exists (
-- Ensure no active user exists for this handle
select 1 from active_users where active_users . handle = inactive_users . handle
)
)
select * from users
where is_banned = 0 and is_deleted = 0 -- select active users directly
or users . id = (
-- select the inactive user with the highest ID if no active user exists for the handle
select max ( id )
from inactive_users_with_no_shadowing_active_user
where users . handle = inactive_users_with_no_shadowing_active_user . handle
)
group by handle having id = max ( id ) ;
2021-07-24 10:19:05 -07:00
2024-02-24 16:45:08 -08:00
create table fake_user_sequence ( latest_fake_id integer not null ) ;
insert into fake_user_sequence values ( 0 x4000000000000000 ) ;
create table lists ( rowid integer primary key ,
is_online boolean not null default 0 ,
online_list_id integer not null default 0 , -- Will be 0 for lists that aren't Twitter Lists
name text not null ,
check ( ( is_online = 0 and online_list_id = 0 ) or ( is_online ! = 0 and online_list_id ! = 0 ) )
check ( rowid ! = 0 )
) ;
create table list_users ( rowid integer primary key ,
list_id integer not null ,
user_id integer not null ,
unique ( list_id , user_id )
2024-02-25 21:58:56 -08:00
foreign key ( list_id ) references lists ( rowid ) on delete cascade
2024-02-24 16:45:08 -08:00
foreign key ( user_id ) references users ( id )
) ;
create index if not exists index_list_users_list_id on list_users ( list_id ) ;
create index if not exists index_list_users_user_id on list_users ( user_id ) ;
2024-12-21 07:53:31 -08:00
insert into lists ( rowid , name ) values ( 1 , ' Offline Follows ' ) ;
2024-02-24 16:45:08 -08:00
insert into list_users ( list_id , user_id ) select 1 , id from users where is_followed = 1 ;
create table follows ( rowid integer primary key ,
follower_id integer not null ,
followee_id integer not null ,
unique ( follower_id , followee_id ) ,
foreign key ( follower_id ) references users ( id )
foreign key ( followee_id ) references users ( id )
) ;
create index if not exists index_follows_followee_id on follows ( followee_id ) ;
create index if not exists index_follows_follower_id on follows ( follower_id ) ;
-- Tweets
-- ------
2021-11-06 13:37:46 -07:00
create table tombstone_types ( rowid integer primary key ,
short_name text not null unique ,
tombstone_text text not null unique
2021-06-27 13:31:30 -07:00
) ;
2021-11-06 13:37:46 -07:00
insert into tombstone_types ( rowid , short_name , tombstone_text ) values
( 1 , ' deleted ' , ' This Tweet was deleted by the Tweet author ' ) ,
2021-12-21 16:05:51 -05:00
( 2 , ' suspended ' , ' This Tweet is from a suspended account ' ) ,
2021-11-06 13:37:46 -07:00
( 3 , ' hidden ' , ' You’ re unable to view this Tweet because this account owner limits who can view their Tweets ' ) ,
2021-12-21 16:05:51 -05:00
( 4 , ' unavailable ' , ' This Tweet is unavailable ' ) ,
( 5 , ' violated ' , ' This Tweet violated the Twitter Rules ' ) ,
2022-02-14 17:15:01 -08:00
( 6 , ' no longer exists ' , ' This Tweet is from an account that no longer exists ' ) ,
2023-10-14 19:45:51 -03:00
( 7 , ' age-restricted ' , ' Age-restricted adult content. This content might not be appropriate for people under 18 years old. To view this media, you’ ll need to log in to Twitter ' ) ,
( 8 , ' newer-version-available ' , ' There’ s a new version of this Tweet ' ) ;
2021-06-27 13:31:30 -07:00
create table tweets ( rowid integer primary key ,
2021-07-24 21:52:39 -07:00
id integer unique not null check ( typeof ( id ) = ' integer ' ) ,
2021-07-25 15:42:43 -07:00
user_id integer not null check ( typeof ( user_id ) = ' integer ' ) ,
2021-06-27 13:31:30 -07:00
text text not null ,
2023-06-08 18:51:50 -03:00
is_expandable bool not null default 0 ,
2021-06-27 13:31:30 -07:00
posted_at integer ,
num_likes integer ,
num_retweets integer ,
num_replies integer ,
num_quote_tweets integer ,
2021-11-22 14:56:57 -08:00
in_reply_to_id integer ,
quoted_tweet_id integer ,
2021-09-27 18:29:55 -07:00
mentions text , -- comma-separated
reply_mentions text , -- comma-separated
hashtags text , -- comma-separated
2022-05-14 16:36:03 -07:00
space_id text ,
2021-11-06 13:37:46 -07:00
tombstone_type integer default 0 ,
is_stub boolean default 0 ,
2021-06-27 13:31:30 -07:00
2021-07-25 15:42:43 -07:00
is_content_downloaded boolean default 0 ,
2021-12-20 14:07:20 -05:00
is_conversation_scraped boolean default 0 ,
last_scraped_at integer not null default 0 ,
2021-07-24 10:19:05 -07:00
foreign key ( user_id ) references users ( id )
2022-05-14 16:36:03 -07:00
foreign key ( space_id ) references spaces ( id )
2021-06-27 13:31:30 -07:00
) ;
2022-12-24 13:47:43 -05:00
create index if not exists index_tweets_in_reply_to_id on tweets ( in_reply_to_id ) ;
2022-12-26 13:08:25 -05:00
create index if not exists index_tweets_user_id on tweets ( user_id ) ;
2023-08-17 18:21:22 -03:00
create index if not exists index_tweets_posted_at on tweets ( posted_at ) ;
2021-06-27 13:31:30 -07:00
2024-02-24 16:45:08 -08:00
-- Tweet content
-- -------------
2021-06-27 13:31:30 -07:00
create table urls ( rowid integer primary key ,
tweet_id integer not null ,
2021-09-17 18:04:12 -07:00
domain text ,
2021-06-27 13:31:30 -07:00
text text not null ,
2024-12-21 07:53:31 -08:00
short_text text not null default ' ' ,
2021-09-17 18:04:12 -07:00
title text ,
description text ,
creator_id integer ,
site_id integer ,
2021-10-10 16:06:47 -07:00
thumbnail_width integer not null ,
thumbnail_height integer not null ,
2021-09-17 18:04:12 -07:00
thumbnail_remote_url text ,
thumbnail_local_path text ,
has_card boolean ,
2021-09-17 20:50:28 -07:00
has_thumbnail boolean ,
2021-09-17 18:04:12 -07:00
is_content_downloaded boolean default 0 ,
2021-06-27 13:31:30 -07:00
unique ( tweet_id , text )
foreign key ( tweet_id ) references tweets ( id )
) ;
2022-12-24 13:47:43 -05:00
create index if not exists index_urls_tweet_id on urls ( tweet_id ) ;
2021-06-27 13:31:30 -07:00
2021-12-12 16:42:32 -08:00
create table polls ( rowid integer primary key ,
2021-12-12 18:42:27 -08:00
id integer unique not null check ( typeof ( id ) = ' integer ' ) ,
2021-12-12 16:42:32 -08:00
tweet_id integer not null ,
num_choices integer not null ,
choice1 text ,
choice1_votes integer ,
choice2 text ,
choice2_votes integer ,
choice3 text ,
choice3_votes integer ,
choice4 text ,
choice4_votes integer ,
voting_duration integer not null , -- in seconds
voting_ends_at integer not null ,
last_scraped_at integer not null ,
foreign key ( tweet_id ) references tweets ( id )
) ;
2022-12-24 13:47:43 -05:00
create index if not exists index_polls_tweet_id on polls ( tweet_id ) ;
2021-12-12 16:42:32 -08:00
2022-05-14 16:04:09 -07:00
2021-06-27 13:31:30 -07:00
create table images ( rowid integer primary key ,
2021-08-04 01:27:14 -07:00
id integer unique not null check ( typeof ( id ) = ' integer ' ) ,
2021-06-27 13:31:30 -07:00
tweet_id integer not null ,
2021-10-10 16:06:47 -07:00
width integer not null ,
height integer not null ,
2021-08-05 14:22:16 -07:00
remote_url text not null unique ,
local_filename text not null unique ,
2021-07-26 17:26:39 -07:00
is_downloaded boolean default 0 ,
2021-07-25 15:42:43 -07:00
foreign key ( tweet_id ) references tweets ( id )
) ;
2022-12-24 13:47:43 -05:00
create index if not exists index_images_tweet_id on images ( tweet_id ) ;
2021-07-25 15:42:43 -07:00
create table videos ( rowid integer primary key ,
2021-08-04 23:41:58 -07:00
id integer unique not null check ( typeof ( id ) = ' integer ' ) ,
2021-07-25 15:42:43 -07:00
tweet_id integer not null ,
2021-10-10 16:06:47 -07:00
width integer not null ,
height integer not null ,
2021-08-05 14:10:46 -07:00
remote_url text not null unique ,
local_filename text not null unique ,
2024-12-21 07:53:31 -08:00
thumbnail_remote_url text not null default ' missing ' ,
thumbnail_local_filename text not null default ' missing ' ,
2021-12-24 16:26:34 -05:00
duration integer not null default 0 ,
view_count integer not null default 0 ,
2021-10-04 21:06:53 -07:00
is_gif boolean default 0 ,
2021-07-26 17:26:39 -07:00
is_downloaded boolean default 0 ,
2022-12-02 20:33:54 -05:00
is_blocked_by_dmca boolean not null default 0 ,
2021-06-27 13:31:30 -07:00
foreign key ( tweet_id ) references tweets ( id )
) ;
2022-12-24 13:47:43 -05:00
create index if not exists index_videos_tweet_id on videos ( tweet_id ) ;
2021-06-27 13:31:30 -07:00
create table hashtags ( rowid integer primary key ,
tweet_id integer not null ,
text text not null ,
unique ( tweet_id , text )
foreign key ( tweet_id ) references tweets ( id )
) ;
2021-11-22 16:55:27 -08:00
2024-02-24 16:45:08 -08:00
-- Retweets
-- --------
create table retweets ( rowid integer primary key ,
retweet_id integer not null unique ,
tweet_id integer not null ,
retweeted_by integer not null ,
retweeted_at integer not null ,
foreign key ( tweet_id ) references tweets ( id )
foreign key ( retweeted_by ) references users ( id )
) ;
create index if not exists index_retweets_retweeted_at on retweets ( retweeted_at ) ;
-- Spaces
-- ------
create table spaces ( rowid integer primary key ,
id text unique not null ,
created_by_id integer ,
short_url text not null ,
state text not null ,
title text not null ,
created_at integer not null ,
started_at integer not null ,
ended_at integer not null ,
updated_at integer not null ,
is_available_for_replay boolean not null ,
replay_watch_count integer ,
live_listeners_count integer ,
is_details_fetched boolean not null default 0 ,
foreign key ( created_by_id ) references users ( id )
) ;
create table space_participants ( rowid integer primary key ,
user_id integer not null ,
space_id not null ,
unique ( user_id , space_id )
foreign key ( space_id ) references spaces ( id )
-- No foreign key for users, since they may not be downloaded yet and I don't want to
-- download every user who joins a space
) ;
-- Likes
-- -----
2023-06-26 13:16:22 -03:00
create table likes ( rowid integer primary key ,
2023-10-13 17:55:40 -03:00
sort_order integer not null , -- Can't be unique because "-1" is used as "unknown" value
2023-06-26 13:16:22 -03:00
user_id integer not null ,
tweet_id integer not null ,
unique ( user_id , tweet_id )
foreign key ( user_id ) references users ( id )
foreign key ( tweet_id ) references tweets ( id )
) ;
2023-10-12 15:34:24 -03:00
create index if not exists index_likes_user_id on likes ( user_id ) ;
create index if not exists index_likes_tweet_id on likes ( tweet_id ) ;
2023-06-26 13:16:22 -03:00
2023-12-26 19:52:37 -06:00
2024-05-28 21:55:42 -07:00
-- Bookmarks
- - - - - - - - - - --
create table bookmarks ( rowid integer primary key ,
sort_order integer not null , -- Can't be unique because "-1" is used as "unknown" value
user_id integer not null ,
tweet_id integer not null ,
unique ( user_id , tweet_id )
foreign key ( tweet_id ) references tweets ( id )
foreign key ( user_id ) references users ( id )
) ;
create index if not exists index_bookmarks_user_id on bookmarks ( user_id ) ;
create index if not exists index_bookmarks_tweet_id on bookmarks ( tweet_id ) ;
2024-02-24 16:45:08 -08:00
-- Direct Messages (DMs)
-- ---------------------
2023-10-12 15:34:24 -03:00
2023-06-22 17:58:50 -03:00
create table chat_rooms ( rowid integer primary key ,
2023-05-30 17:55:12 -03:00
id text unique not null ,
2023-05-29 17:31:26 -07:00
type text not null ,
2023-05-30 17:55:12 -03:00
last_messaged_at integer not null ,
2023-11-19 20:37:22 -08:00
is_nsfw boolean not null ,
-- Group DM info
created_at integer not null ,
created_by_user_id integer not null ,
name text not null default ' ' ,
avatar_image_remote_url text not null default ' ' ,
avatar_image_local_path text not null default ' '
2023-05-30 17:55:12 -03:00
) ;
create table chat_room_participants ( rowid integer primary key ,
chat_room_id text not null ,
user_id integer not null ,
last_read_event_id integer not null ,
is_chat_settings_valid boolean not null default 0 ,
is_notifications_disabled boolean not null ,
is_mention_notifications_disabled boolean not null ,
is_read_only boolean not null ,
is_trusted boolean not null ,
is_muted boolean not null ,
status text not null ,
unique ( chat_room_id , user_id )
) ;
2023-05-29 17:31:26 -07:00
2023-05-30 17:55:12 -03:00
create table chat_messages ( rowid integer primary key ,
2023-05-29 17:31:26 -07:00
id integer unique not null check ( typeof ( id ) = ' integer ' ) ,
2023-06-22 17:58:50 -03:00
chat_room_id text not null ,
2023-05-30 17:55:12 -03:00
sender_id integer not null ,
sent_at integer not null ,
request_id text not null ,
2023-06-22 17:58:50 -03:00
in_reply_to_id integer ,
2023-05-30 17:55:12 -03:00
text text not null ,
2023-11-19 23:33:04 -08:00
embedded_tweet_id integer not null default 0 ,
2023-06-22 17:58:50 -03:00
foreign key ( chat_room_id ) references chat_rooms ( id )
2023-05-29 17:31:26 -07:00
foreign key ( sender_id ) references users ( id )
2023-06-22 17:58:50 -03:00
) ;
2023-05-29 17:31:26 -07:00
2023-05-30 17:55:12 -03:00
create table chat_message_reactions ( rowid integer primary key ,
2023-05-29 17:31:26 -07:00
id integer unique not null check ( typeof ( id ) = ' integer ' ) ,
2023-05-30 17:55:12 -03:00
message_id integer not null ,
sender_id integer not null ,
sent_at integer not null ,
2023-11-18 14:55:07 -08:00
emoji text not null ,
2023-06-22 18:40:46 -03:00
foreign key ( message_id ) references chat_messages ( id )
2023-05-29 17:31:26 -07:00
foreign key ( sender_id ) references users ( id )
2023-05-30 17:55:12 -03:00
) ;
2023-05-29 17:31:26 -07:00
2024-03-11 21:12:38 -07:00
create table chat_message_images ( rowid integer primary key ,
id integer unique not null check ( typeof ( id ) = ' integer ' ) ,
chat_message_id integer not null ,
width integer not null ,
height integer not null ,
remote_url text not null unique ,
local_filename text not null unique ,
is_downloaded boolean default 0 ,
foreign key ( chat_message_id ) references chat_messages ( id )
) ;
create index if not exists index_chat_message_images_chat_message_id on chat_message_images ( chat_message_id ) ;
create table chat_message_videos ( rowid integer primary key ,
id integer unique not null check ( typeof ( id ) = ' integer ' ) ,
chat_message_id integer not null ,
width integer not null ,
height integer not null ,
remote_url text not null unique ,
local_filename text not null unique ,
2024-12-21 07:53:31 -08:00
thumbnail_remote_url text not null default ' missing ' ,
thumbnail_local_filename text not null default ' missing ' ,
2024-03-11 21:12:38 -07:00
duration integer not null default 0 ,
view_count integer not null default 0 ,
is_gif boolean default 0 ,
is_downloaded boolean default 0 ,
is_blocked_by_dmca boolean not null default 0 ,
foreign key ( chat_message_id ) references chat_messages ( id )
) ;
create index if not exists index_chat_message_videos_chat_message_id on chat_message_videos ( chat_message_id ) ;
create table chat_message_urls ( rowid integer primary key ,
chat_message_id integer not null ,
domain text ,
text text not null ,
2024-12-21 07:53:31 -08:00
short_text text not null default ' ' ,
2024-03-11 21:12:38 -07:00
title text ,
description text ,
creator_id integer ,
site_id integer ,
thumbnail_width integer not null ,
thumbnail_height integer not null ,
thumbnail_remote_url text ,
thumbnail_local_path text ,
has_card boolean ,
has_thumbnail boolean ,
is_content_downloaded boolean default 0 ,
unique ( chat_message_id , text )
foreign key ( chat_message_id ) references chat_messages ( id )
) ;
create index if not exists index_chat_message_urls_chat_message_id on chat_message_urls ( chat_message_id ) ;
2024-02-24 16:45:08 -08:00
2024-08-25 22:54:18 -07:00
-- Notifications
-- -------------
create table notification_types ( rowid integer primary key ,
name text not null unique
) ;
insert into notification_types ( rowid , name ) values
( 1 , ' like ' ) ,
( 2 , ' retweet ' ) ,
( 3 , ' quote-tweet ' ) ,
( 4 , ' reply ' ) ,
( 5 , ' follow ' ) ,
( 6 , ' mention ' ) ,
( 7 , ' user is LIVE ' ) ,
( 8 , ' poll ended ' ) ,
( 9 , ' login ' ) ,
( 10 , ' community pinned post ' ) ,
( 11 , ' new recommended post ' ) ;
create table notifications ( rowid integer primary key ,
id text unique ,
type integer not null ,
sent_at integer not null ,
sort_index integer not null ,
user_id integer not null , -- user who received the notification
action_user_id integer references users ( id ) , -- user who triggered the notification
action_tweet_id integer references tweets ( id ) , -- tweet associated with the notification
action_retweet_id integer references retweets ( retweet_id ) ,
2024-08-28 19:22:09 -07:00
has_detail boolean not null default 0 ,
last_scraped_at not null default 0 ,
2024-08-25 22:54:18 -07:00
foreign key ( type ) references notification_types ( rowid )
foreign key ( user_id ) references users ( id )
) ;
create table notification_tweets ( rowid integer primary key ,
notification_id not null references notifications ( id ) ,
tweet_id not null references tweets ( id ) ,
unique ( notification_id , tweet_id )
) ;
2024-08-28 19:20:29 -07:00
create table notification_retweets ( rowid integer primary key ,
notification_id not null references notifications ( id ) ,
retweet_id not null references retweets ( retweet_id ) ,
unique ( notification_id , retweet_id )
) ;
2024-08-25 22:54:18 -07:00
create table notification_users ( rowid integer primary key ,
notification_id not null references notifications ( id ) ,
user_id not null references users ( id ) ,
unique ( notification_id , user_id )
) ;
2024-02-24 16:45:08 -08:00
-- Meta
-- ----
2023-10-12 15:34:24 -03:00
create table database_version ( rowid integer primary key ,
version_number integer not null unique
) ;
2024-10-23 22:00:38 -07:00
insert into database_version ( version_number ) values ( 32 ) ;