mirror of
https://github.com/simplex-chat/simplex-chat.git
synced 2025-06-28 20:29:53 +00:00
script to add message views to database (#195)
This commit is contained in:
parent
c2c05816f3
commit
809a87ce61
3 changed files with 144 additions and 15 deletions
47
README.md
47
README.md
|
@ -12,7 +12,7 @@
|
|||
|
||||
SimpleX chat prototype is a thin terminal UI on top of [SimpleXMQ](https://github.com/simplex-chat/simplexmq) message broker that uses [SMP protocols](https://github.com/simplex-chat/simplexmq/blob/master/protocol). The motivation for SimpleX chat is [presented here](./simplex.md). See [simplex.chat](https://simplex.chat) website for chat demo and the explanations of the system and how SMP protocol works.
|
||||
|
||||
**NEW in v0.5.4: [messages persistence](#access-chat-history)**
|
||||
**NEW in v0.5.4: [message persistence](#access-chat-history)**
|
||||
|
||||
**NEW in v0.5.0: [user contact addresses](#user-contact-addresses-alpha)**
|
||||
|
||||
|
@ -200,7 +200,7 @@ $ stack install
|
|||
|
||||
To start the chat client, run `simplex-chat` from the terminal. If you get `simplex-chat: command not found`, see [Troubleshooting on Unix](#troubleshooting-on-unix).
|
||||
|
||||
By default, app data directory is created in the home directory (`~/.simplex`, or `%APPDATA%/simplex` on Windows), and two SQLite database files `simplex.chat.db` and `simplex.agent.db` are initialized in it.
|
||||
By default, app data directory is created in the home directory (`~/.simplex`, or `%APPDATA%/simplex` on Windows), and two SQLite database files `simplex_v1_chat.db` and `simplex_v1_agent.db` are initialized in it.
|
||||
|
||||
To specify a different file path prefix for the database files use `-d` command line option:
|
||||
|
||||
|
@ -208,7 +208,7 @@ To specify a different file path prefix for the database files use `-d` command
|
|||
$ simplex-chat -d alice
|
||||
```
|
||||
|
||||
Running above, for example, would create `alice.chat.db` and `alice.agent.db` database files in current directory.
|
||||
Running above, for example, would create `alice_chat.db` and `alice_agent.db` database files in current directory.
|
||||
|
||||
Default SMP servers are hosted on Linode (London, UK and Fremont, CA) - they are [pre-configured in the app](https://github.com/simplex-chat/simplex-chat/blob/master/src/Simplex/Chat/Options.hs#L40). Base-64 encoded string after server host is the transport key digest.
|
||||
|
||||
|
@ -280,37 +280,54 @@ Use `/help address` for other commands.
|
|||
|
||||
SimpleX chat stores all your contacts and conversations in a local SQLite database, making it private and portable by design, owned and controlled by user.
|
||||
|
||||
> **Please note:** Starting with v1.0.0 message views are not created as part of database initialization. Run the below script to create them in your database.
|
||||
|
||||
```sh
|
||||
curl -o- https://raw.githubusercontent.com/simplex-chat/simplex-chat/master/message_views.sql | sqlite3 ~/.simplex/simplex_v1_chat.db
|
||||
```
|
||||
|
||||
You can view and search your chat history by querying your database:
|
||||
|
||||
```
|
||||
sqlite3 ~/.simplex/simplex.chat.db
|
||||
```sh
|
||||
sqlite3 ~/.simplex/simplex_v1_chat.db
|
||||
```
|
||||
|
||||
Now you can run queries against `direct_messages`, `group_messages` and `all_messages` (or their simpler alternatives `direct_messages_plain`, `group_messages_plain` and `all_messages_plain`), for example:
|
||||
|
||||
```sql
|
||||
-- you can put these or your preferred settings into ~/.sqliterc to persist across sqlite3 client sessions
|
||||
-- you can put these or your preferred settings into ~/.sqliterc
|
||||
-- to persist across sqlite3 client sessions
|
||||
.mode column
|
||||
.headers on
|
||||
.nullvalue NULL
|
||||
|
||||
-- simple views into direct, group and all_messages with user's messages deduplicated for group and all_messages
|
||||
-- only 'x.msg.new' ("new message") chat events - filters out service events
|
||||
-- simple views into direct, group and all_messages
|
||||
-- with user's messages deduplicated for group and all_messages;
|
||||
-- only 'x.msg.new' ("new message") chat events - filters out service events;
|
||||
-- msg_sent is 0 for received, 1 for sent
|
||||
select * from direct_messages_plain;
|
||||
select * from group_messages_plain;
|
||||
select * from all_messages_plain;
|
||||
|
||||
-- query other details of your chat history with regular SQL
|
||||
select * from direct_messages where msg_sent = 1 and chat_msg_event = 'x.file'; -- files you offered for sending
|
||||
select * from direct_messages where msg_sent = 0 and contact = 'catherine' and msg_body like '%cats%'; -- everything catherine sent related to cats
|
||||
select * from group_messages where group_name = 'team' and contact = 'alice'; -- all correspondence with alice in #team
|
||||
-- query other details of your chat history with regular SQL, for example:
|
||||
-- files you offered for sending
|
||||
select * from direct_messages where msg_sent = 1 and chat_msg_event = 'x.file';
|
||||
-- everything catherine sent related to cats
|
||||
select * from direct_messages where msg_sent = 0 and contact = 'catherine' and msg_body like '%cats%';
|
||||
-- all correspondence with alice in #team
|
||||
select * from group_messages where group_name = 'team' and contact = 'alice';
|
||||
|
||||
-- aggregate your chat data
|
||||
select contact_or_group, num_messages from (
|
||||
select contact as contact_or_group, count(1) as num_messages from direct_messages_plain group by contact
|
||||
select
|
||||
contact as contact_or_group, count(1) as num_messages
|
||||
from direct_messages_plain group by contact
|
||||
union
|
||||
select group_name as contact_or_group, count(1) as num_messages from group_messages_plain group by group_name
|
||||
) order by num_messages desc;
|
||||
select
|
||||
group_name as contact_or_group, count(1) as num_messages
|
||||
from group_messages_plain group by group_name
|
||||
)
|
||||
order by num_messages desc;
|
||||
```
|
||||
|
||||
**Convenience queries**
|
||||
|
|
110
message_views.sql
Normal file
110
message_views.sql
Normal file
|
@ -0,0 +1,110 @@
|
|||
CREATE VIEW direct_messages AS
|
||||
SELECT
|
||||
ct.local_display_name AS contact,
|
||||
m.message_id AS message_id,
|
||||
m.msg_sent AS msg_sent,
|
||||
m.chat_msg_event AS chat_msg_event,
|
||||
m.msg_body AS msg_body,
|
||||
md.msg_delivery_id AS delivery_id,
|
||||
datetime(md.chat_ts) AS chat_dt,
|
||||
md.agent_msg_meta AS msg_meta,
|
||||
mde.delivery_status AS delivery_status,
|
||||
datetime(mde.created_at) AS delivery_status_dt
|
||||
FROM messages m
|
||||
JOIN msg_deliveries md ON md.message_id = m.message_id
|
||||
JOIN (
|
||||
SELECT msg_delivery_id, MAX(created_at) MaxDate
|
||||
FROM msg_delivery_events
|
||||
GROUP BY msg_delivery_id
|
||||
) MaxDates ON MaxDates.msg_delivery_id = md.msg_delivery_id
|
||||
JOIN msg_delivery_events mde ON mde.msg_delivery_id = MaxDates.msg_delivery_id
|
||||
AND mde.created_at = MaxDates.MaxDate
|
||||
JOIN connections c ON c.connection_id = md.connection_id
|
||||
JOIN contacts ct ON ct.contact_id = c.contact_id
|
||||
ORDER BY chat_dt DESC;
|
||||
|
||||
CREATE VIEW direct_messages_plain AS
|
||||
SELECT
|
||||
dm.contact AS contact,
|
||||
dm.msg_sent AS msg_sent,
|
||||
dm.msg_body AS msg_body,
|
||||
dm.chat_dt AS chat_dt
|
||||
FROM direct_messages dm
|
||||
WHERE dm.chat_msg_event = 'x.msg.new';
|
||||
|
||||
CREATE VIEW group_messages AS
|
||||
SELECT
|
||||
g.local_display_name AS group_name,
|
||||
gm.local_display_name AS contact,
|
||||
m.message_id AS message_id,
|
||||
m.msg_sent AS msg_sent,
|
||||
m.chat_msg_event AS chat_msg_event,
|
||||
m.msg_body AS msg_body,
|
||||
md.msg_delivery_id AS delivery_id,
|
||||
datetime(md.chat_ts) AS chat_dt,
|
||||
md.agent_msg_meta AS msg_meta,
|
||||
mde.delivery_status AS delivery_status,
|
||||
datetime(mde.created_at) AS delivery_status_dt
|
||||
FROM messages m
|
||||
JOIN msg_deliveries md ON md.message_id = m.message_id
|
||||
JOIN (
|
||||
SELECT msg_delivery_id, MAX(created_at) MaxDate
|
||||
FROM msg_delivery_events
|
||||
GROUP BY msg_delivery_id
|
||||
) MaxDates ON MaxDates.msg_delivery_id = md.msg_delivery_id
|
||||
JOIN msg_delivery_events mde ON mde.msg_delivery_id = MaxDates.msg_delivery_id
|
||||
AND mde.created_at = MaxDates.MaxDate
|
||||
JOIN connections c ON c.connection_id = md.connection_id
|
||||
JOIN group_members gm ON gm.group_member_id = c.group_member_id
|
||||
JOIN groups g ON g.group_id = gm.group_id
|
||||
ORDER BY chat_dt DESC;
|
||||
|
||||
CREATE VIEW group_messages_plain AS
|
||||
SELECT
|
||||
gm.group_name AS group_name,
|
||||
(CASE WHEN gm.msg_sent = 0 THEN gm.contact ELSE gm.group_name END) AS contact,
|
||||
gm.msg_sent AS msg_sent,
|
||||
gm.msg_body AS msg_body,
|
||||
gm.chat_dt AS chat_dt
|
||||
FROM group_messages gm
|
||||
JOIN (
|
||||
SELECT message_id, MIN(delivery_id) MinDeliveryId
|
||||
FROM group_messages
|
||||
GROUP BY message_id
|
||||
) Deduplicated ON Deduplicated.message_id = gm.message_id
|
||||
AND Deduplicated.MinDeliveryId = gm.delivery_id
|
||||
WHERE gm.chat_msg_event = 'x.msg.new';
|
||||
|
||||
CREATE VIEW all_messages (
|
||||
group_name,
|
||||
contact,
|
||||
message_id,
|
||||
msg_sent,
|
||||
chat_msg_event,
|
||||
msg_body,
|
||||
delivery_id,
|
||||
chat_dt,
|
||||
msg_meta,
|
||||
delivery_status,
|
||||
delivery_status_dt
|
||||
) AS
|
||||
SELECT * FROM (
|
||||
SELECT NULL AS group_name, * FROM direct_messages
|
||||
UNION
|
||||
SELECT * FROM group_messages
|
||||
)
|
||||
ORDER BY chat_dt DESC;
|
||||
|
||||
CREATE VIEW all_messages_plain (
|
||||
group_name,
|
||||
contact,
|
||||
msg_sent,
|
||||
msg_body,
|
||||
chat_dt
|
||||
) AS
|
||||
SELECT * FROM (
|
||||
SELECT NULL AS group_name, * FROM direct_messages_plain
|
||||
UNION
|
||||
SELECT * FROM group_messages_plain
|
||||
)
|
||||
ORDER BY chat_dt DESC;
|
|
@ -39,6 +39,8 @@ CREATE TABLE msg_delivery_events (
|
|||
UNIQUE (msg_delivery_id, delivery_status)
|
||||
);
|
||||
|
||||
-- TODO delete all message views when merging migrations
|
||||
|
||||
CREATE VIEW direct_messages AS
|
||||
SELECT
|
||||
ct.local_display_name AS contact,
|
||||
|
|
Loading…
Add table
Add a link
Reference in a new issue