1 -- ------------------------------------------
2 -- Friendica 2022.12-rc (Giant Rhubarb)
3 -- DB_UPDATE_VERSION 1500
4 -- ------------------------------------------
10 CREATE TABLE IF NOT EXISTS `gserver` (
11 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
12 `url` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
13 `nurl` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
14 `version` varchar(255) NOT NULL DEFAULT '' COMMENT '',
15 `site_name` varchar(255) NOT NULL DEFAULT '' COMMENT '',
16 `info` text COMMENT '',
17 `register_policy` tinyint NOT NULL DEFAULT 0 COMMENT '',
18 `registered-users` int unsigned NOT NULL DEFAULT 0 COMMENT 'Number of registered users',
19 `active-week-users` int unsigned COMMENT 'Number of active users in the last week',
20 `active-month-users` int unsigned COMMENT 'Number of active users in the last month',
21 `active-halfyear-users` int unsigned COMMENT 'Number of active users in the last six month',
22 `local-posts` int unsigned COMMENT 'Number of local posts',
23 `local-comments` int unsigned COMMENT 'Number of local comments',
24 `directory-type` tinyint DEFAULT 0 COMMENT 'Type of directory service (Poco, Mastodon)',
25 `poco` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
26 `noscrape` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
27 `network` char(4) NOT NULL DEFAULT '' COMMENT '',
28 `protocol` tinyint unsigned COMMENT 'The protocol of the server',
29 `platform` varchar(255) NOT NULL DEFAULT '' COMMENT '',
30 `relay-subscribe` boolean NOT NULL DEFAULT '0' COMMENT 'Has the server subscribed to the relay system',
31 `relay-scope` varchar(10) NOT NULL DEFAULT '' COMMENT 'The scope of messages that the server wants to get',
32 `detection-method` tinyint unsigned COMMENT 'Method that had been used to detect that server',
33 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
34 `last_poco_query` datetime DEFAULT '0001-01-01 00:00:00' COMMENT '',
35 `last_contact` datetime DEFAULT '0001-01-01 00:00:00' COMMENT 'Last successful connection request',
36 `last_failure` datetime DEFAULT '0001-01-01 00:00:00' COMMENT 'Last failed connection request',
37 `failed` boolean COMMENT 'Connection failed',
38 `next_contact` datetime DEFAULT '0001-01-01 00:00:00' COMMENT 'Next connection request',
40 UNIQUE INDEX `nurl` (`nurl`(190)),
41 INDEX `next_contact` (`next_contact`),
42 INDEX `network` (`network`)
43 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Global servers';
48 CREATE TABLE IF NOT EXISTS `user` (
49 `uid` mediumint unsigned NOT NULL auto_increment COMMENT 'sequential ID',
50 `parent-uid` mediumint unsigned COMMENT 'The parent user that has full control about this user',
51 `guid` varchar(64) NOT NULL DEFAULT '' COMMENT 'A unique identifier for this user',
52 `username` varchar(255) NOT NULL DEFAULT '' COMMENT 'Name that this user is known by',
53 `password` varchar(255) NOT NULL DEFAULT '' COMMENT 'encrypted password',
54 `legacy_password` boolean NOT NULL DEFAULT '0' COMMENT 'Is the password hash double-hashed?',
55 `nickname` varchar(255) NOT NULL DEFAULT '' COMMENT 'nick- and user name',
56 `email` varchar(255) NOT NULL DEFAULT '' COMMENT 'the users email address',
57 `openid` varchar(255) NOT NULL DEFAULT '' COMMENT '',
58 `timezone` varchar(128) NOT NULL DEFAULT '' COMMENT 'PHP-legal timezone',
59 `language` varchar(32) NOT NULL DEFAULT 'en' COMMENT 'default language',
60 `register_date` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'timestamp of registration',
61 `login_date` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'timestamp of last login',
62 `last-activity` date COMMENT 'Day of the last activity',
63 `default-location` varchar(255) NOT NULL DEFAULT '' COMMENT 'Default for item.location',
64 `allow_location` boolean NOT NULL DEFAULT '0' COMMENT '1 allows to display the location',
65 `theme` varchar(255) NOT NULL DEFAULT '' COMMENT 'user theme preference',
66 `pubkey` text COMMENT 'RSA public key 4096 bit',
67 `prvkey` text COMMENT 'RSA private key 4096 bit',
68 `spubkey` text COMMENT '',
69 `sprvkey` text COMMENT '',
70 `verified` boolean NOT NULL DEFAULT '0' COMMENT 'user is verified through email',
71 `blocked` boolean NOT NULL DEFAULT '0' COMMENT '1 for user is blocked',
72 `blockwall` boolean NOT NULL DEFAULT '0' COMMENT 'Prohibit contacts to post to the profile page of the user',
73 `hidewall` boolean NOT NULL DEFAULT '0' COMMENT 'Hide profile details from unkown viewers',
74 `blocktags` boolean NOT NULL DEFAULT '0' COMMENT 'Prohibit contacts to tag the post of this user',
75 `unkmail` boolean NOT NULL DEFAULT '0' COMMENT 'Permit unknown people to send private mails to this user',
76 `cntunkmail` int unsigned NOT NULL DEFAULT 10 COMMENT '',
77 `notify-flags` smallint unsigned NOT NULL DEFAULT 65535 COMMENT 'email notification options',
78 `page-flags` tinyint unsigned NOT NULL DEFAULT 0 COMMENT 'page/profile type',
79 `account-type` tinyint unsigned NOT NULL DEFAULT 0 COMMENT '',
80 `prvnets` boolean NOT NULL DEFAULT '0' COMMENT '',
81 `pwdreset` varchar(255) COMMENT 'Password reset request token',
82 `pwdreset_time` datetime COMMENT 'Timestamp of the last password reset request',
83 `maxreq` int unsigned NOT NULL DEFAULT 10 COMMENT '',
84 `expire` int unsigned NOT NULL DEFAULT 0 COMMENT 'Delay in days before deleting user-related posts. Scope is controlled by pConfig.',
85 `account_removed` boolean NOT NULL DEFAULT '0' COMMENT 'if 1 the account is removed',
86 `account_expired` boolean NOT NULL DEFAULT '0' COMMENT '',
87 `account_expires_on` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'timestamp when account expires and will be deleted',
88 `expire_notification_sent` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'timestamp of last warning of account expiration',
89 `def_gid` int unsigned NOT NULL DEFAULT 0 COMMENT '',
90 `allow_cid` mediumtext COMMENT 'default permission for this user',
91 `allow_gid` mediumtext COMMENT 'default permission for this user',
92 `deny_cid` mediumtext COMMENT 'default permission for this user',
93 `deny_gid` mediumtext COMMENT 'default permission for this user',
94 `openidserver` text COMMENT '',
96 INDEX `nickname` (`nickname`(32)),
97 INDEX `parent-uid` (`parent-uid`),
98 INDEX `guid` (`guid`),
99 INDEX `email` (`email`(64)),
100 FOREIGN KEY (`parent-uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
101 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='The local users';
106 CREATE TABLE IF NOT EXISTS `item-uri` (
107 `id` int unsigned NOT NULL auto_increment,
108 `uri` varbinary(383) NOT NULL COMMENT 'URI of an item',
109 `guid` varbinary(255) COMMENT 'A unique identifier for an item',
111 UNIQUE INDEX `uri` (`uri`),
112 INDEX `guid` (`guid`)
113 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='URI and GUID for items';
118 CREATE TABLE IF NOT EXISTS `contact` (
119 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
120 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'Owner User id',
121 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
122 `updated` datetime DEFAULT '0001-01-01 00:00:00' COMMENT 'Date of last contact update',
123 `network` char(4) NOT NULL DEFAULT '' COMMENT 'Network of the contact',
124 `name` varchar(255) NOT NULL DEFAULT '' COMMENT 'Name that this contact is known by',
125 `nick` varchar(255) NOT NULL DEFAULT '' COMMENT 'Nick- and user name of the contact',
126 `location` varchar(255) DEFAULT '' COMMENT '',
127 `about` text COMMENT '',
128 `keywords` text COMMENT 'public keywords (interests) of the contact',
129 `xmpp` varchar(255) NOT NULL DEFAULT '' COMMENT 'XMPP address',
130 `matrix` varchar(255) NOT NULL DEFAULT '' COMMENT 'Matrix address',
131 `avatar` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
132 `header` varbinary(383) COMMENT 'Header picture',
133 `url` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
134 `nurl` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
135 `uri-id` int unsigned COMMENT 'Id of the item-uri table entry that contains the contact url',
136 `addr` varchar(255) NOT NULL DEFAULT '' COMMENT '',
137 `alias` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
138 `pubkey` text COMMENT 'RSA public key 4096 bit',
139 `prvkey` text COMMENT 'RSA private key 4096 bit',
140 `batch` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
141 `notify` varbinary(383) COMMENT '',
142 `poll` varbinary(383) COMMENT '',
143 `subscribe` varbinary(383) COMMENT '',
144 `last-update` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Date of the last try to update the contact info',
145 `next-update` datetime COMMENT 'Next connection request',
146 `success_update` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Date of the last successful contact update',
147 `failure_update` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Date of the last failed update',
148 `failed` boolean COMMENT 'Connection failed',
149 `term-date` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
150 `last-item` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'date of the last post',
151 `last-discovery` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'date of the last follower discovery',
152 `local-data` boolean COMMENT 'Is true when there are posts with this contact on the system',
153 `blocked` boolean NOT NULL DEFAULT '1' COMMENT 'Node-wide block status',
154 `block_reason` text COMMENT 'Node-wide block reason',
155 `readonly` boolean NOT NULL DEFAULT '0' COMMENT 'posts of the contact are readonly',
156 `contact-type` tinyint NOT NULL DEFAULT 0 COMMENT 'Person, organisation, news, community, relay',
157 `manually-approve` boolean COMMENT 'Contact requests have to be approved manually',
158 `archive` boolean NOT NULL DEFAULT '0' COMMENT '',
159 `unsearchable` boolean NOT NULL DEFAULT '0' COMMENT 'Contact prefers to not be searchable',
160 `sensitive` boolean NOT NULL DEFAULT '0' COMMENT 'Contact posts sensitive content',
161 `baseurl` varbinary(383) DEFAULT '' COMMENT 'baseurl of the contact',
162 `gsid` int unsigned COMMENT 'Global Server ID',
163 `bd` date NOT NULL DEFAULT '0001-01-01' COMMENT '',
164 `reason` text COMMENT '',
165 `self` boolean NOT NULL DEFAULT '0' COMMENT '1 if the contact is the user him/her self',
166 `remote_self` boolean NOT NULL DEFAULT '0' COMMENT '',
167 `rel` tinyint unsigned NOT NULL DEFAULT 0 COMMENT 'The kind of the relation between the user and the contact',
168 `protocol` char(4) NOT NULL DEFAULT '' COMMENT 'Protocol of the contact',
169 `subhub` boolean NOT NULL DEFAULT '0' COMMENT '',
170 `hub-verify` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
171 `rating` tinyint NOT NULL DEFAULT 0 COMMENT 'Automatically detected feed poll frequency',
172 `priority` tinyint unsigned NOT NULL DEFAULT 0 COMMENT 'Feed poll priority',
173 `attag` varchar(255) NOT NULL DEFAULT '' COMMENT '',
174 `hidden` boolean NOT NULL DEFAULT '0' COMMENT '',
175 `pending` boolean NOT NULL DEFAULT '1' COMMENT 'Contact request is pending',
176 `deleted` boolean NOT NULL DEFAULT '0' COMMENT 'Contact has been deleted',
177 `info` mediumtext COMMENT '',
178 `notify_new_posts` boolean NOT NULL DEFAULT '0' COMMENT '',
179 `fetch_further_information` tinyint unsigned NOT NULL DEFAULT 0 COMMENT '',
180 `ffi_keyword_denylist` text COMMENT '',
181 `photo` varbinary(383) DEFAULT '' COMMENT 'Link to the profile photo of the contact',
182 `thumb` varbinary(383) DEFAULT '' COMMENT 'Link to the profile photo (thumb size)',
183 `micro` varbinary(383) DEFAULT '' COMMENT 'Link to the profile photo (micro size)',
184 `name-date` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
185 `uri-date` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
186 `avatar-date` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
187 `request` varbinary(383) COMMENT '',
188 `confirm` varbinary(383) COMMENT '',
189 `poco` varbinary(383) COMMENT '',
190 `writable` boolean NOT NULL DEFAULT '0' COMMENT '',
191 `forum` boolean NOT NULL DEFAULT '0' COMMENT 'contact is a forum. Deprecated, use \'contact-type\' = \'community\' and \'manually-approve\' = false instead',
192 `prv` boolean NOT NULL DEFAULT '0' COMMENT 'contact is a private group. Deprecated, use \'contact-type\' = \'community\' and \'manually-approve\' = true instead',
193 `bdyear` varchar(4) NOT NULL DEFAULT '' COMMENT '',
194 `site-pubkey` text COMMENT 'Deprecated',
195 `gender` varchar(32) NOT NULL DEFAULT '' COMMENT 'Deprecated',
196 `duplex` boolean NOT NULL DEFAULT '0' COMMENT 'Deprecated',
197 `issued-id` varbinary(383) NOT NULL DEFAULT '' COMMENT 'Deprecated',
198 `dfrn-id` varbinary(383) NOT NULL DEFAULT '' COMMENT 'Deprecated',
199 `aes_allow` boolean NOT NULL DEFAULT '0' COMMENT 'Deprecated',
200 `ret-aes` boolean NOT NULL DEFAULT '0' COMMENT 'Deprecated',
201 `usehub` boolean NOT NULL DEFAULT '0' COMMENT 'Deprecated',
202 `closeness` tinyint unsigned NOT NULL DEFAULT 99 COMMENT 'Deprecated',
203 `profile-id` int unsigned COMMENT 'Deprecated',
205 INDEX `uid_name` (`uid`,`name`(190)),
206 INDEX `self_uid` (`self`,`uid`),
207 INDEX `alias_uid` (`alias`(128),`uid`),
208 INDEX `pending_uid` (`pending`,`uid`),
209 INDEX `blocked_uid` (`blocked`,`uid`),
210 INDEX `uid_rel_network_poll` (`uid`,`rel`,`network`,`poll`(64),`archive`),
211 INDEX `uid_network_batch` (`uid`,`network`,`batch`(64)),
212 INDEX `batch_contact-type` (`batch`(64),`contact-type`),
213 INDEX `addr_uid` (`addr`(128),`uid`),
214 INDEX `nurl_uid` (`nurl`(128),`uid`),
215 INDEX `nick_uid` (`nick`(128),`uid`),
216 INDEX `attag_uid` (`attag`(96),`uid`),
217 INDEX `network_uid_lastupdate` (`network`,`uid`,`last-update`),
218 INDEX `uid_network_self_lastupdate` (`uid`,`network`,`self`,`last-update`),
219 INDEX `next-update` (`next-update`),
220 INDEX `local-data-next-update` (`local-data`,`next-update`),
221 INDEX `uid_lastitem` (`uid`,`last-item`),
222 INDEX `baseurl` (`baseurl`(64)),
223 INDEX `uid_contact-type` (`uid`,`contact-type`),
224 INDEX `uid_self_contact-type` (`uid`,`self`,`contact-type`),
225 INDEX `self_network_uid` (`self`,`network`,`uid`),
226 INDEX `gsid_uid_failed` (`gsid`,`uid`,`failed`),
227 INDEX `uri-id` (`uri-id`),
228 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE,
229 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
230 FOREIGN KEY (`gsid`) REFERENCES `gserver` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT
231 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='contact table';
236 CREATE TABLE IF NOT EXISTS `tag` (
237 `id` int unsigned NOT NULL auto_increment COMMENT '',
238 `name` varchar(96) NOT NULL DEFAULT '' COMMENT '',
239 `url` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
240 `type` tinyint unsigned COMMENT 'Type of the tag (Unknown, General Collection, Follower Collection or Account)',
242 UNIQUE INDEX `type_name_url` (`name`,`url`),
244 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='tags and mentions';
247 -- TABLE permissionset
249 CREATE TABLE IF NOT EXISTS `permissionset` (
250 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
251 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'Owner id of this permission set',
252 `allow_cid` mediumtext COMMENT 'Access Control - list of allowed contact.id \'<19><78>\'',
253 `allow_gid` mediumtext COMMENT 'Access Control - list of allowed groups',
254 `deny_cid` mediumtext COMMENT 'Access Control - list of denied contact.id',
255 `deny_gid` mediumtext COMMENT 'Access Control - list of denied groups',
257 INDEX `uid_allow_cid_allow_gid_deny_cid_deny_gid` (`uid`,`allow_cid`(50),`allow_gid`(30),`deny_cid`(50),`deny_gid`(30)),
258 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
259 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='';
264 CREATE TABLE IF NOT EXISTS `verb` (
265 `id` smallint unsigned NOT NULL auto_increment,
266 `name` varchar(100) NOT NULL DEFAULT '' COMMENT '',
268 INDEX `name` (`name`)
269 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Activity Verbs';
272 -- TABLE 2fa_app_specific_password
274 CREATE TABLE IF NOT EXISTS `2fa_app_specific_password` (
275 `id` mediumint unsigned NOT NULL auto_increment COMMENT 'Password ID for revocation',
276 `uid` mediumint unsigned NOT NULL COMMENT 'User ID',
277 `description` varchar(255) COMMENT 'Description of the usage of the password',
278 `hashed_password` varchar(255) NOT NULL COMMENT 'Hashed password',
279 `generated` datetime NOT NULL COMMENT 'Datetime the password was generated',
280 `last_used` datetime COMMENT 'Datetime the password was last used',
282 INDEX `uid_description` (`uid`,`description`(190)),
283 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
284 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Two-factor app-specific _password';
287 -- TABLE 2fa_recovery_codes
289 CREATE TABLE IF NOT EXISTS `2fa_recovery_codes` (
290 `uid` mediumint unsigned NOT NULL COMMENT 'User ID',
291 `code` varchar(50) NOT NULL COMMENT 'Recovery code string',
292 `generated` datetime NOT NULL COMMENT 'Datetime the code was generated',
293 `used` datetime COMMENT 'Datetime the code was used',
294 PRIMARY KEY(`uid`,`code`),
295 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
296 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Two-factor authentication recovery codes';
299 -- TABLE 2fa_trusted_browser
301 CREATE TABLE IF NOT EXISTS `2fa_trusted_browser` (
302 `cookie_hash` varchar(80) NOT NULL COMMENT 'Trusted cookie hash',
303 `uid` mediumint unsigned NOT NULL COMMENT 'User ID',
304 `user_agent` text COMMENT 'User agent string',
305 `trusted` boolean NOT NULL DEFAULT '1' COMMENT 'Whenever this browser should be trusted or not',
306 `created` datetime NOT NULL COMMENT 'Datetime the trusted browser was recorded',
307 `last_used` datetime COMMENT 'Datetime the trusted browser was last used',
308 PRIMARY KEY(`cookie_hash`),
310 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
311 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Two-factor authentication trusted browsers';
314 -- TABLE account-suggestion
316 CREATE TABLE IF NOT EXISTS `account-suggestion` (
317 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the account url',
318 `uid` mediumint unsigned NOT NULL COMMENT 'User ID',
319 `level` smallint unsigned COMMENT 'level of closeness',
320 `ignore` boolean NOT NULL DEFAULT '0' COMMENT 'If set, this account will not be suggested again',
321 PRIMARY KEY(`uid`,`uri-id`),
322 INDEX `uri-id_uid` (`uri-id`,`uid`),
323 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
324 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
325 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Account suggestion';
328 -- TABLE account-user
330 CREATE TABLE IF NOT EXISTS `account-user` (
331 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
332 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the account url',
333 `uid` mediumint unsigned NOT NULL COMMENT 'User ID',
335 UNIQUE INDEX `uri-id_uid` (`uri-id`,`uid`),
336 INDEX `uid_uri-id` (`uid`,`uri-id`),
337 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
338 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
339 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Remote and local accounts';
344 CREATE TABLE IF NOT EXISTS `addon` (
345 `id` int unsigned NOT NULL auto_increment COMMENT '',
346 `name` varchar(50) NOT NULL DEFAULT '' COMMENT 'addon base (file)name',
347 `version` varchar(50) NOT NULL DEFAULT '' COMMENT 'currently unused',
348 `installed` boolean NOT NULL DEFAULT '0' COMMENT 'currently always 1',
349 `hidden` boolean NOT NULL DEFAULT '0' COMMENT 'currently unused',
350 `timestamp` int unsigned NOT NULL DEFAULT 0 COMMENT 'file timestamp to check for reloads',
351 `plugin_admin` boolean NOT NULL DEFAULT '0' COMMENT '1 = has admin config, 0 = has no admin config',
353 INDEX `installed_name` (`installed`,`name`),
354 UNIQUE INDEX `name` (`name`)
355 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='registered addons';
360 CREATE TABLE IF NOT EXISTS `apcontact` (
361 `url` varbinary(383) NOT NULL COMMENT 'URL of the contact',
362 `uri-id` int unsigned COMMENT 'Id of the item-uri table entry that contains the apcontact url',
363 `uuid` varbinary(255) COMMENT '',
364 `type` varchar(20) NOT NULL COMMENT '',
365 `following` varbinary(383) COMMENT '',
366 `followers` varbinary(383) COMMENT '',
367 `inbox` varbinary(383) NOT NULL COMMENT '',
368 `outbox` varbinary(383) COMMENT '',
369 `sharedinbox` varbinary(383) COMMENT '',
370 `featured` varbinary(383) COMMENT 'Address for the collection of featured posts',
371 `featured-tags` varbinary(383) COMMENT 'Address for the collection of featured tags',
372 `manually-approve` boolean COMMENT '',
373 `discoverable` boolean COMMENT 'Mastodon extension: true if profile is published in their directory',
374 `suspended` boolean COMMENT 'Mastodon extension: true if profile is suspended',
375 `nick` varchar(255) NOT NULL DEFAULT '' COMMENT '',
376 `name` varchar(255) COMMENT '',
377 `about` text COMMENT '',
378 `xmpp` varchar(255) COMMENT 'XMPP address',
379 `matrix` varchar(255) COMMENT 'Matrix address',
380 `photo` varbinary(383) COMMENT '',
381 `header` varbinary(383) COMMENT 'Header picture',
382 `addr` varchar(255) COMMENT '',
383 `alias` varbinary(383) COMMENT '',
384 `pubkey` text COMMENT '',
385 `subscribe` varbinary(383) COMMENT '',
386 `baseurl` varbinary(383) COMMENT 'baseurl of the ap contact',
387 `gsid` int unsigned COMMENT 'Global Server ID',
388 `generator` varchar(255) COMMENT 'Name of the contact\'s system',
389 `following_count` int unsigned DEFAULT 0 COMMENT 'Number of following contacts',
390 `followers_count` int unsigned DEFAULT 0 COMMENT 'Number of followers',
391 `statuses_count` int unsigned DEFAULT 0 COMMENT 'Number of posts',
392 `updated` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
394 INDEX `addr` (`addr`(32)),
395 INDEX `alias` (`alias`(190)),
396 INDEX `followers` (`followers`(190)),
397 INDEX `baseurl` (`baseurl`(190)),
398 INDEX `sharedinbox` (`sharedinbox`(190)),
399 INDEX `gsid` (`gsid`),
400 UNIQUE INDEX `uri-id` (`uri-id`),
401 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
402 FOREIGN KEY (`gsid`) REFERENCES `gserver` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT
403 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='ActivityPub compatible contacts - used in the ActivityPub implementation';
408 CREATE TABLE IF NOT EXISTS `application` (
409 `id` int unsigned NOT NULL auto_increment COMMENT 'generated index',
410 `client_id` varchar(64) NOT NULL COMMENT '',
411 `client_secret` varchar(64) NOT NULL COMMENT '',
412 `name` varchar(255) NOT NULL COMMENT '',
413 `redirect_uri` varbinary(383) NOT NULL COMMENT '',
414 `website` varbinary(383) COMMENT '',
415 `scopes` varchar(255) COMMENT '',
416 `read` boolean COMMENT 'Read scope',
417 `write` boolean COMMENT 'Write scope',
418 `follow` boolean COMMENT 'Follow scope',
419 `push` boolean COMMENT 'Push scope',
421 UNIQUE INDEX `client_id` (`client_id`)
422 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='OAuth application';
425 -- TABLE application-marker
427 CREATE TABLE IF NOT EXISTS `application-marker` (
428 `application-id` int unsigned NOT NULL COMMENT '',
429 `uid` mediumint unsigned NOT NULL COMMENT 'Owner User id',
430 `timeline` varchar(64) NOT NULL COMMENT 'Marker (home, notifications)',
431 `last_read_id` varbinary(383) COMMENT 'Marker id for the timeline',
432 `version` smallint unsigned COMMENT 'Version number',
433 `updated_at` datetime COMMENT 'creation time',
434 PRIMARY KEY(`application-id`,`uid`,`timeline`),
435 INDEX `uid_id` (`uid`),
436 FOREIGN KEY (`application-id`) REFERENCES `application` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
437 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
438 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Timeline marker';
441 -- TABLE application-token
443 CREATE TABLE IF NOT EXISTS `application-token` (
444 `application-id` int unsigned NOT NULL COMMENT '',
445 `uid` mediumint unsigned NOT NULL COMMENT 'Owner User id',
446 `code` varchar(64) NOT NULL COMMENT '',
447 `access_token` varchar(64) NOT NULL COMMENT '',
448 `created_at` datetime NOT NULL COMMENT 'creation time',
449 `scopes` varchar(255) COMMENT '',
450 `read` boolean COMMENT 'Read scope',
451 `write` boolean COMMENT 'Write scope',
452 `follow` boolean COMMENT 'Follow scope',
453 `push` boolean COMMENT 'Push scope',
454 PRIMARY KEY(`application-id`,`uid`),
455 INDEX `uid_id` (`uid`,`application-id`),
456 FOREIGN KEY (`application-id`) REFERENCES `application` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
457 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
458 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='OAuth user token';
463 CREATE TABLE IF NOT EXISTS `attach` (
464 `id` int unsigned NOT NULL auto_increment COMMENT 'generated index',
465 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'Owner User id',
466 `hash` varchar(64) NOT NULL DEFAULT '' COMMENT 'hash',
467 `filename` varchar(255) NOT NULL DEFAULT '' COMMENT 'filename of original',
468 `filetype` varchar(64) NOT NULL DEFAULT '' COMMENT 'mimetype',
469 `filesize` int unsigned NOT NULL DEFAULT 0 COMMENT 'size in bytes',
470 `data` longblob NOT NULL COMMENT 'file data',
471 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'creation time',
472 `edited` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'last edit time',
473 `allow_cid` mediumtext COMMENT 'Access Control - list of allowed contact.id \'<19><78>',
474 `allow_gid` mediumtext COMMENT 'Access Control - list of allowed groups',
475 `deny_cid` mediumtext COMMENT 'Access Control - list of denied contact.id',
476 `deny_gid` mediumtext COMMENT 'Access Control - list of denied groups',
477 `backend-class` tinytext COMMENT 'Storage backend class',
478 `backend-ref` text COMMENT 'Storage backend data reference',
481 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
482 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='file attachments';
487 CREATE TABLE IF NOT EXISTS `cache` (
488 `k` varbinary(255) NOT NULL COMMENT 'cache key',
489 `v` mediumtext COMMENT 'cached serialized value',
490 `expires` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'datetime of cache expiration',
491 `updated` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'datetime of cache insertion',
493 INDEX `k_expires` (`k`,`expires`)
494 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Stores temporary data';
499 CREATE TABLE IF NOT EXISTS `config` (
500 `id` int unsigned NOT NULL auto_increment COMMENT '',
501 `cat` varbinary(50) NOT NULL DEFAULT '' COMMENT '',
502 `k` varbinary(50) NOT NULL DEFAULT '' COMMENT '',
503 `v` mediumtext COMMENT '',
505 UNIQUE INDEX `cat_k` (`cat`,`k`)
506 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='main configuration storage';
509 -- TABLE contact-relation
511 CREATE TABLE IF NOT EXISTS `contact-relation` (
512 `cid` int unsigned NOT NULL DEFAULT 0 COMMENT 'contact the related contact had interacted with',
513 `relation-cid` int unsigned NOT NULL DEFAULT 0 COMMENT 'related contact who had interacted with the contact',
514 `last-interaction` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Date of the last interaction',
515 `follow-updated` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Date of the last update of the contact relationship',
516 `follows` boolean NOT NULL DEFAULT '0' COMMENT '',
517 PRIMARY KEY(`cid`,`relation-cid`),
518 INDEX `relation-cid` (`relation-cid`),
519 FOREIGN KEY (`cid`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
520 FOREIGN KEY (`relation-cid`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
521 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Contact relations';
526 CREATE TABLE IF NOT EXISTS `conv` (
527 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
528 `guid` varbinary(255) NOT NULL DEFAULT '' COMMENT 'A unique identifier for this conversation',
529 `recips` text COMMENT 'sender_handle;recipient_handle',
530 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'Owner User id',
531 `creator` varchar(255) NOT NULL DEFAULT '' COMMENT 'handle of creator',
532 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'creation timestamp',
533 `updated` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'edited timestamp',
534 `subject` text COMMENT 'subject of initial message',
537 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
538 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='private messages';
543 CREATE TABLE IF NOT EXISTS `workerqueue` (
544 `id` int unsigned NOT NULL auto_increment COMMENT 'Auto incremented worker task id',
545 `command` varchar(100) COMMENT 'Task command',
546 `parameter` mediumtext COMMENT 'Task parameter',
547 `priority` tinyint unsigned NOT NULL DEFAULT 0 COMMENT 'Task priority',
548 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Creation date',
549 `pid` int unsigned NOT NULL DEFAULT 0 COMMENT 'Process id of the worker',
550 `executed` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Execution date',
551 `next_try` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Next retrial date',
552 `retrial` tinyint NOT NULL DEFAULT 0 COMMENT 'Retrial counter',
553 `done` boolean NOT NULL DEFAULT '0' COMMENT 'Marked 1 when the task was done - will be deleted later',
555 INDEX `command` (`command`),
556 INDEX `done_command_parameter` (`done`,`command`,`parameter`(64)),
557 INDEX `done_executed` (`done`,`executed`),
558 INDEX `done_priority_retrial_created` (`done`,`priority`,`retrial`,`created`),
559 INDEX `done_priority_next_try` (`done`,`priority`,`next_try`),
560 INDEX `done_pid_next_try` (`done`,`pid`,`next_try`),
561 INDEX `done_pid_retrial` (`done`,`pid`,`retrial`),
562 INDEX `done_pid_priority_created` (`done`,`pid`,`priority`,`created`)
563 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Background tasks queue entries';
566 -- TABLE delayed-post
568 CREATE TABLE IF NOT EXISTS `delayed-post` (
569 `id` int unsigned NOT NULL auto_increment,
570 `uri` varbinary(383) COMMENT 'URI of the post that will be distributed later',
571 `uid` mediumint unsigned COMMENT 'Owner User id',
572 `delayed` datetime COMMENT 'delay time',
573 `wid` int unsigned COMMENT 'Workerqueue id',
575 UNIQUE INDEX `uid_uri` (`uid`,`uri`(190)),
577 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE,
578 FOREIGN KEY (`wid`) REFERENCES `workerqueue` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
579 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Posts that are about to be distributed at a later time';
582 -- TABLE diaspora-contact
584 CREATE TABLE IF NOT EXISTS `diaspora-contact` (
585 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the contact URL',
586 `addr` varchar(255) COMMENT '',
587 `alias` varchar(255) COMMENT '',
588 `nick` varchar(255) COMMENT '',
589 `name` varchar(255) COMMENT '',
590 `given-name` varchar(255) COMMENT '',
591 `family-name` varchar(255) COMMENT '',
592 `photo` varchar(255) COMMENT '',
593 `photo-medium` varchar(255) COMMENT '',
594 `photo-small` varchar(255) COMMENT '',
595 `batch` varchar(255) COMMENT '',
596 `notify` varchar(255) COMMENT '',
597 `poll` varchar(255) COMMENT '',
598 `subscribe` varchar(255) COMMENT '',
599 `searchable` boolean COMMENT '',
600 `pubkey` text COMMENT '',
601 `gsid` int unsigned COMMENT 'Global Server ID',
602 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
603 `updated` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
604 `interacting_count` int unsigned DEFAULT 0 COMMENT 'Number of contacts this contact interactes with',
605 `interacted_count` int unsigned DEFAULT 0 COMMENT 'Number of contacts that interacted with this contact',
606 `post_count` int unsigned DEFAULT 0 COMMENT 'Number of posts and comments',
607 PRIMARY KEY(`uri-id`),
608 UNIQUE INDEX `addr` (`addr`),
609 INDEX `alias` (`alias`),
610 INDEX `gsid` (`gsid`),
611 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
612 FOREIGN KEY (`gsid`) REFERENCES `gserver` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT
613 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Diaspora compatible contacts - used in the Diaspora implementation';
616 -- TABLE diaspora-interaction
618 CREATE TABLE IF NOT EXISTS `diaspora-interaction` (
619 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the item uri',
620 `interaction` mediumtext COMMENT 'The Diaspora interaction',
621 PRIMARY KEY(`uri-id`),
622 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
623 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Signed Diaspora Interaction';
628 CREATE TABLE IF NOT EXISTS `endpoint` (
629 `url` varbinary(383) NOT NULL COMMENT 'URL of the contact',
630 `type` varchar(20) NOT NULL COMMENT '',
631 `owner-uri-id` int unsigned COMMENT 'Id of the item-uri table entry that contains the apcontact url',
633 UNIQUE INDEX `owner-uri-id_type` (`owner-uri-id`,`type`),
634 FOREIGN KEY (`owner-uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
635 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='ActivityPub endpoints - used in the ActivityPub implementation';
640 CREATE TABLE IF NOT EXISTS `event` (
641 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
642 `guid` varbinary(255) NOT NULL DEFAULT '' COMMENT '',
643 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'Owner User id',
644 `cid` int unsigned NOT NULL DEFAULT 0 COMMENT 'contact_id (ID of the contact in contact table)',
645 `uri` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
646 `uri-id` int unsigned COMMENT 'Id of the item-uri table entry that contains the event uri',
647 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'creation time',
648 `edited` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'last edit time',
649 `start` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'event start time',
650 `finish` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'event end time',
651 `summary` text COMMENT 'short description or title of the event',
652 `desc` text COMMENT 'event description',
653 `location` text COMMENT 'event location',
654 `type` varchar(20) NOT NULL DEFAULT '' COMMENT 'event or birthday',
655 `nofinish` boolean NOT NULL DEFAULT '0' COMMENT 'if event does have no end this is 1',
656 `ignore` boolean NOT NULL DEFAULT '0' COMMENT '0 or 1',
657 `allow_cid` mediumtext COMMENT 'Access Control - list of allowed contact.id \'<19><78>\'',
658 `allow_gid` mediumtext COMMENT 'Access Control - list of allowed groups',
659 `deny_cid` mediumtext COMMENT 'Access Control - list of denied contact.id',
660 `deny_gid` mediumtext COMMENT 'Access Control - list of denied groups',
662 INDEX `uid_start` (`uid`,`start`),
664 INDEX `uri-id` (`uri-id`),
665 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE,
666 FOREIGN KEY (`cid`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
667 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
668 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Events';
673 CREATE TABLE IF NOT EXISTS `fetch-entry` (
674 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
675 `url` varbinary(383) COMMENT 'url that awaiting to be fetched',
676 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Creation date of the fetch request',
677 `wid` int unsigned COMMENT 'Workerqueue id',
679 UNIQUE INDEX `url` (`url`),
680 INDEX `created` (`created`),
682 FOREIGN KEY (`wid`) REFERENCES `workerqueue` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
683 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='';
688 CREATE TABLE IF NOT EXISTS `fsuggest` (
689 `id` int unsigned NOT NULL auto_increment COMMENT '',
690 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'User id',
691 `cid` int unsigned NOT NULL DEFAULT 0 COMMENT '',
692 `name` varchar(255) NOT NULL DEFAULT '' COMMENT '',
693 `url` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
694 `request` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
695 `photo` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
696 `note` text COMMENT '',
697 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
701 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE,
702 FOREIGN KEY (`cid`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
703 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='friend suggestion stuff';
708 CREATE TABLE IF NOT EXISTS `group` (
709 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
710 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'Owner User id',
711 `visible` boolean NOT NULL DEFAULT '0' COMMENT '1 indicates the member list is not private',
712 `deleted` boolean NOT NULL DEFAULT '0' COMMENT '1 indicates the group has been deleted',
713 `cid` int unsigned COMMENT 'Contact id of forum. When this field is filled then the members are synced automatically.',
714 `name` varchar(255) NOT NULL DEFAULT '' COMMENT 'human readable name of group',
718 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE,
719 FOREIGN KEY (`cid`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
720 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='privacy groups, group info';
723 -- TABLE group_member
725 CREATE TABLE IF NOT EXISTS `group_member` (
726 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
727 `gid` int unsigned NOT NULL DEFAULT 0 COMMENT 'groups.id of the associated group',
728 `contact-id` int unsigned NOT NULL DEFAULT 0 COMMENT 'contact.id of the member assigned to the associated group',
730 INDEX `contactid` (`contact-id`),
731 UNIQUE INDEX `gid_contactid` (`gid`,`contact-id`),
732 FOREIGN KEY (`gid`) REFERENCES `group` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
733 FOREIGN KEY (`contact-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
734 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='privacy groups, member info';
739 CREATE TABLE IF NOT EXISTS `gserver-tag` (
740 `gserver-id` int unsigned NOT NULL DEFAULT 0 COMMENT 'The id of the gserver',
741 `tag` varchar(100) NOT NULL DEFAULT '' COMMENT 'Tag that the server has subscribed',
742 PRIMARY KEY(`gserver-id`,`tag`),
744 FOREIGN KEY (`gserver-id`) REFERENCES `gserver` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
745 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Tags that the server has subscribed';
750 CREATE TABLE IF NOT EXISTS `hook` (
751 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
752 `hook` varbinary(100) NOT NULL DEFAULT '' COMMENT 'name of hook',
753 `file` varbinary(200) NOT NULL DEFAULT '' COMMENT 'relative filename of hook handler',
754 `function` varbinary(200) NOT NULL DEFAULT '' COMMENT 'function name of hook handler',
755 `priority` smallint unsigned NOT NULL DEFAULT 0 COMMENT 'not yet implemented - can be used to sort conflicts in hook handling by calling handlers in priority order',
757 INDEX `priority` (`priority`),
758 UNIQUE INDEX `hook_file_function` (`hook`,`file`,`function`)
759 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='addon hook registry';
764 CREATE TABLE IF NOT EXISTS `inbox-entry` (
765 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
766 `activity-id` varbinary(383) COMMENT 'id of the incoming activity',
767 `object-id` varbinary(383) COMMENT '',
768 `in-reply-to-id` varbinary(383) COMMENT '',
769 `conversation` varbinary(383) COMMENT '',
770 `type` varchar(64) COMMENT 'Type of the activity',
771 `object-type` varchar(64) COMMENT 'Type of the object activity',
772 `object-object-type` varchar(64) COMMENT 'Type of the object\'s object activity',
773 `received` datetime COMMENT 'Receiving date',
774 `activity` mediumtext COMMENT 'The JSON activity',
775 `signer` varchar(255) COMMENT '',
776 `push` boolean COMMENT 'Is the entry pushed or have pulled it?',
777 `trust` boolean COMMENT 'Do we trust this entry?',
778 `wid` int unsigned COMMENT 'Workerqueue id',
780 UNIQUE INDEX `activity-id` (`activity-id`),
781 INDEX `object-id` (`object-id`),
782 INDEX `received` (`received`),
784 FOREIGN KEY (`wid`) REFERENCES `workerqueue` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
785 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Incoming activity';
788 -- TABLE inbox-entry-receiver
790 CREATE TABLE IF NOT EXISTS `inbox-entry-receiver` (
791 `queue-id` int unsigned NOT NULL COMMENT '',
792 `uid` mediumint unsigned NOT NULL COMMENT 'User id',
793 PRIMARY KEY(`queue-id`,`uid`),
795 FOREIGN KEY (`queue-id`) REFERENCES `inbox-entry` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
796 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
797 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Receiver for the incoming activity';
800 -- TABLE inbox-status
802 CREATE TABLE IF NOT EXISTS `inbox-status` (
803 `url` varbinary(383) NOT NULL COMMENT 'URL of the inbox',
804 `uri-id` int unsigned COMMENT 'Item-uri id of inbox url',
805 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Creation date of this entry',
806 `success` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Date of the last successful delivery',
807 `failure` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Date of the last failed delivery',
808 `previous` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Previous delivery date',
809 `archive` boolean NOT NULL DEFAULT '0' COMMENT 'Is the inbox archived?',
810 `shared` boolean NOT NULL DEFAULT '0' COMMENT 'Is it a shared inbox?',
812 INDEX `uri-id` (`uri-id`),
813 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
814 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Status of ActivityPub inboxes';
819 CREATE TABLE IF NOT EXISTS `intro` (
820 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
821 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'User id',
822 `fid` int unsigned COMMENT 'deprecated',
823 `contact-id` int unsigned NOT NULL DEFAULT 0 COMMENT '',
824 `suggest-cid` int unsigned COMMENT 'Suggested contact',
825 `knowyou` boolean NOT NULL DEFAULT '0' COMMENT '',
826 `duplex` boolean NOT NULL DEFAULT '0' COMMENT 'deprecated',
827 `note` text COMMENT '',
828 `hash` varbinary(255) NOT NULL DEFAULT '' COMMENT '',
829 `datetime` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
830 `blocked` boolean NOT NULL DEFAULT '0' COMMENT 'deprecated',
831 `ignore` boolean NOT NULL DEFAULT '0' COMMENT '',
833 INDEX `contact-id` (`contact-id`),
834 INDEX `suggest-cid` (`suggest-cid`),
836 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE,
837 FOREIGN KEY (`contact-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
838 FOREIGN KEY (`suggest-cid`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
839 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='';
844 CREATE TABLE IF NOT EXISTS `locks` (
845 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
846 `name` varchar(128) NOT NULL DEFAULT '' COMMENT '',
847 `locked` boolean NOT NULL DEFAULT '0' COMMENT '',
848 `pid` int unsigned NOT NULL DEFAULT 0 COMMENT 'Process ID',
849 `expires` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'datetime of cache expiration',
851 INDEX `name_expires` (`name`,`expires`)
852 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='';
857 CREATE TABLE IF NOT EXISTS `mail` (
858 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
859 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'Owner User id',
860 `guid` varbinary(255) NOT NULL DEFAULT '' COMMENT 'A unique identifier for this private message',
861 `from-name` varchar(255) NOT NULL DEFAULT '' COMMENT 'name of the sender',
862 `from-photo` varbinary(383) NOT NULL DEFAULT '' COMMENT 'contact photo link of the sender',
863 `from-url` varbinary(383) NOT NULL DEFAULT '' COMMENT 'profile linke of the sender',
864 `contact-id` varbinary(255) COMMENT 'contact.id',
865 `author-id` int unsigned COMMENT 'Link to the contact table with uid=0 of the author of the mail',
866 `convid` int unsigned COMMENT 'conv.id',
867 `title` varchar(255) NOT NULL DEFAULT '' COMMENT '',
868 `body` mediumtext COMMENT '',
869 `seen` boolean NOT NULL DEFAULT '0' COMMENT 'if message visited it is 1',
870 `reply` boolean NOT NULL DEFAULT '0' COMMENT '',
871 `replied` boolean NOT NULL DEFAULT '0' COMMENT '',
872 `unknown` boolean NOT NULL DEFAULT '0' COMMENT 'if sender not in the contact table this is 1',
873 `uri` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
874 `uri-id` int unsigned COMMENT 'Item-uri id of the related mail',
875 `parent-uri` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
876 `parent-uri-id` int unsigned COMMENT 'Item-uri id of the parent of the related mail',
877 `thr-parent` varbinary(383) COMMENT '',
878 `thr-parent-id` int unsigned COMMENT 'Id of the item-uri table that contains the thread parent uri',
879 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'creation time of the private message',
881 INDEX `uid_seen` (`uid`,`seen`),
882 INDEX `convid` (`convid`),
883 INDEX `uri` (`uri`(64)),
884 INDEX `parent-uri` (`parent-uri`(64)),
885 INDEX `contactid` (`contact-id`(32)),
886 INDEX `author-id` (`author-id`),
887 INDEX `uri-id` (`uri-id`),
888 INDEX `parent-uri-id` (`parent-uri-id`),
889 INDEX `thr-parent-id` (`thr-parent-id`),
890 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE,
891 FOREIGN KEY (`author-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT,
892 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
893 FOREIGN KEY (`parent-uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
894 FOREIGN KEY (`thr-parent-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
895 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='private messages';
900 CREATE TABLE IF NOT EXISTS `mailacct` (
901 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
902 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'User id',
903 `server` varchar(255) NOT NULL DEFAULT '' COMMENT '',
904 `port` smallint unsigned NOT NULL DEFAULT 0 COMMENT '',
905 `ssltype` varchar(16) NOT NULL DEFAULT '' COMMENT '',
906 `mailbox` varchar(255) NOT NULL DEFAULT '' COMMENT '',
907 `user` varchar(255) NOT NULL DEFAULT '' COMMENT '',
908 `pass` text COMMENT '',
909 `reply_to` varchar(255) NOT NULL DEFAULT '' COMMENT '',
910 `action` tinyint unsigned NOT NULL DEFAULT 0 COMMENT '',
911 `movetofolder` varchar(255) NOT NULL DEFAULT '' COMMENT '',
912 `pubmail` boolean NOT NULL DEFAULT '0' COMMENT '',
913 `last_check` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
916 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
917 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Mail account data for fetching mails';
922 CREATE TABLE IF NOT EXISTS `manage` (
923 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
924 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'User id',
925 `mid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'User id',
927 UNIQUE INDEX `uid_mid` (`uid`,`mid`),
929 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE,
930 FOREIGN KEY (`mid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
931 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='table of accounts that can manage each other';
934 -- TABLE notification
936 CREATE TABLE IF NOT EXISTS `notification` (
937 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
938 `uid` mediumint unsigned COMMENT 'Owner User id',
939 `vid` smallint unsigned COMMENT 'Id of the verb table entry that contains the activity verbs',
940 `type` smallint unsigned COMMENT '',
941 `actor-id` int unsigned COMMENT 'Link to the contact table with uid=0 of the actor that caused the notification',
942 `target-uri-id` int unsigned COMMENT 'Item-uri id of the related post',
943 `parent-uri-id` int unsigned COMMENT 'Item-uri id of the parent of the related post',
944 `created` datetime COMMENT '',
945 `seen` boolean DEFAULT '0' COMMENT 'Seen on the desktop',
946 `dismissed` boolean DEFAULT '0' COMMENT 'Dismissed via the API',
948 UNIQUE INDEX `uid_vid_type_actor-id_target-uri-id` (`uid`,`vid`,`type`,`actor-id`,`target-uri-id`),
950 INDEX `actor-id` (`actor-id`),
951 INDEX `target-uri-id` (`target-uri-id`),
952 INDEX `parent-uri-id` (`parent-uri-id`),
953 INDEX `seen_uid` (`seen`,`uid`),
954 INDEX `uid_type_parent-uri-id_actor-id` (`uid`,`type`,`parent-uri-id`,`actor-id`),
955 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE,
956 FOREIGN KEY (`vid`) REFERENCES `verb` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT,
957 FOREIGN KEY (`actor-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
958 FOREIGN KEY (`target-uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
959 FOREIGN KEY (`parent-uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
960 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='notifications';
965 CREATE TABLE IF NOT EXISTS `notify` (
966 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
967 `type` smallint unsigned NOT NULL DEFAULT 0 COMMENT '',
968 `name` varchar(255) NOT NULL DEFAULT '' COMMENT '',
969 `url` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
970 `photo` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
971 `date` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
972 `msg` mediumtext COMMENT '',
973 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'Owner User id',
974 `link` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
975 `iid` int unsigned COMMENT '',
976 `parent` int unsigned COMMENT '',
977 `uri-id` int unsigned COMMENT 'Item-uri id of the related post',
978 `parent-uri-id` int unsigned COMMENT 'Item-uri id of the parent of the related post',
979 `seen` boolean NOT NULL DEFAULT '0' COMMENT '',
980 `verb` varchar(100) NOT NULL DEFAULT '' COMMENT '',
981 `otype` varchar(10) NOT NULL DEFAULT '' COMMENT '',
982 `name_cache` tinytext COMMENT 'Cached bbcode parsing of name',
983 `msg_cache` mediumtext COMMENT 'Cached bbcode parsing of msg',
985 INDEX `seen_uid_date` (`seen`,`uid`,`date`),
986 INDEX `uid_date` (`uid`,`date`),
987 INDEX `uid_type_link` (`uid`,`type`,`link`(190)),
988 INDEX `uri-id` (`uri-id`),
989 INDEX `parent-uri-id` (`parent-uri-id`),
990 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE,
991 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
992 FOREIGN KEY (`parent-uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
993 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='[Deprecated] User notifications';
996 -- TABLE notify-threads
998 CREATE TABLE IF NOT EXISTS `notify-threads` (
999 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
1000 `notify-id` int unsigned NOT NULL DEFAULT 0 COMMENT '',
1001 `master-parent-item` int unsigned COMMENT 'Deprecated',
1002 `master-parent-uri-id` int unsigned COMMENT 'Item-uri id of the parent of the related post',
1003 `parent-item` int unsigned NOT NULL DEFAULT 0 COMMENT '',
1004 `receiver-uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'User id',
1006 INDEX `master-parent-uri-id` (`master-parent-uri-id`),
1007 INDEX `receiver-uid` (`receiver-uid`),
1008 INDEX `notify-id` (`notify-id`),
1009 FOREIGN KEY (`notify-id`) REFERENCES `notify` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1010 FOREIGN KEY (`master-parent-uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1011 FOREIGN KEY (`receiver-uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
1012 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='';
1017 CREATE TABLE IF NOT EXISTS `oembed` (
1018 `url` varbinary(383) NOT NULL COMMENT 'page url',
1019 `maxwidth` mediumint unsigned NOT NULL COMMENT 'Maximum width passed to Oembed',
1020 `content` mediumtext COMMENT 'OEmbed data of the page',
1021 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'datetime of creation',
1022 PRIMARY KEY(`url`,`maxwidth`),
1023 INDEX `created` (`created`)
1024 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='cache for OEmbed queries';
1027 -- TABLE openwebauth-token
1029 CREATE TABLE IF NOT EXISTS `openwebauth-token` (
1030 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
1031 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'User id - currently unused',
1032 `type` varchar(32) NOT NULL DEFAULT '' COMMENT 'Verify type',
1033 `token` varchar(255) NOT NULL DEFAULT '' COMMENT 'A generated token',
1034 `meta` varchar(255) NOT NULL DEFAULT '' COMMENT '',
1035 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'datetime of creation',
1037 INDEX `uid` (`uid`),
1038 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
1039 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Store OpenWebAuth token to verify contacts';
1044 CREATE TABLE IF NOT EXISTS `parsed_url` (
1045 `url_hash` binary(64) NOT NULL COMMENT 'page url hash',
1046 `guessing` boolean NOT NULL DEFAULT '0' COMMENT 'is the \'guessing\' mode active?',
1047 `oembed` boolean NOT NULL DEFAULT '0' COMMENT 'is the data the result of oembed?',
1048 `url` text NOT NULL COMMENT 'page url',
1049 `content` mediumtext COMMENT 'page data',
1050 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'datetime of creation',
1051 `expires` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'datetime of expiration',
1052 PRIMARY KEY(`url_hash`,`guessing`,`oembed`),
1053 INDEX `created` (`created`),
1054 INDEX `expires` (`expires`)
1055 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='cache for \'parse_url\' queries';
1060 CREATE TABLE IF NOT EXISTS `pconfig` (
1061 `id` int unsigned NOT NULL auto_increment COMMENT 'Primary key',
1062 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'User id',
1063 `cat` varchar(50) NOT NULL DEFAULT '' COMMENT 'Category',
1064 `k` varchar(100) NOT NULL DEFAULT '' COMMENT 'Key',
1065 `v` mediumtext COMMENT 'Value',
1067 UNIQUE INDEX `uid_cat_k` (`uid`,`cat`,`k`),
1068 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
1069 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='personal (per user) configuration storage';
1074 CREATE TABLE IF NOT EXISTS `photo` (
1075 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
1076 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'Owner User id',
1077 `contact-id` int unsigned NOT NULL DEFAULT 0 COMMENT 'contact.id',
1078 `guid` char(16) NOT NULL DEFAULT '' COMMENT 'A unique identifier for this photo',
1079 `resource-id` char(32) NOT NULL DEFAULT '' COMMENT '',
1080 `hash` char(32) COMMENT 'hash value of the photo',
1081 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'creation date',
1082 `edited` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'last edited date',
1083 `title` varchar(255) NOT NULL DEFAULT '' COMMENT '',
1084 `desc` text COMMENT '',
1085 `album` varchar(255) NOT NULL DEFAULT '' COMMENT 'The name of the album to which the photo belongs',
1086 `photo-type` tinyint unsigned COMMENT 'User avatar, user banner, contact avatar, contact banner or default',
1087 `filename` varchar(255) NOT NULL DEFAULT '' COMMENT '',
1088 `type` varchar(30) NOT NULL DEFAULT 'image/jpeg',
1089 `height` smallint unsigned NOT NULL DEFAULT 0 COMMENT '',
1090 `width` smallint unsigned NOT NULL DEFAULT 0 COMMENT '',
1091 `datasize` int unsigned NOT NULL DEFAULT 0 COMMENT '',
1092 `blurhash` varbinary(255) COMMENT 'BlurHash representation of the photo',
1093 `data` mediumblob NOT NULL COMMENT '',
1094 `scale` tinyint unsigned NOT NULL DEFAULT 0 COMMENT '',
1095 `profile` boolean NOT NULL DEFAULT '0' COMMENT '',
1096 `allow_cid` mediumtext COMMENT 'Access Control - list of allowed contact.id \'<19><78>\'',
1097 `allow_gid` mediumtext COMMENT 'Access Control - list of allowed groups',
1098 `deny_cid` mediumtext COMMENT 'Access Control - list of denied contact.id',
1099 `deny_gid` mediumtext COMMENT 'Access Control - list of denied groups',
1100 `accessible` boolean NOT NULL DEFAULT '0' COMMENT 'Make photo publicly accessible, ignoring permissions',
1101 `backend-class` tinytext COMMENT 'Storage backend class',
1102 `backend-ref` text COMMENT 'Storage backend data reference',
1103 `updated` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
1105 INDEX `contactid` (`contact-id`),
1106 INDEX `uid_contactid` (`uid`,`contact-id`),
1107 INDEX `uid_profile` (`uid`,`profile`),
1108 INDEX `uid_album_scale_created` (`uid`,`album`(32),`scale`,`created`),
1109 INDEX `uid_album_resource-id_created` (`uid`,`album`(32),`resource-id`,`created`),
1110 INDEX `resource-id` (`resource-id`),
1111 INDEX `uid_photo-type` (`uid`,`photo-type`),
1112 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE RESTRICT,
1113 FOREIGN KEY (`contact-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT
1114 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='photo storage';
1119 CREATE TABLE IF NOT EXISTS `post` (
1120 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the item uri',
1121 `parent-uri-id` int unsigned COMMENT 'Id of the item-uri table that contains the parent uri',
1122 `thr-parent-id` int unsigned COMMENT 'Id of the item-uri table that contains the thread parent uri',
1123 `external-id` int unsigned COMMENT 'Id of the item-uri table entry that contains the external uri',
1124 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Creation timestamp.',
1125 `edited` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Date of last edit (default is created)',
1126 `received` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'datetime',
1127 `gravity` tinyint unsigned NOT NULL DEFAULT 0 COMMENT '',
1128 `network` char(4) NOT NULL DEFAULT '' COMMENT 'Network from where the item comes from',
1129 `owner-id` int unsigned NOT NULL DEFAULT 0 COMMENT 'Link to the contact table with uid=0 of the owner of this item',
1130 `author-id` int unsigned NOT NULL DEFAULT 0 COMMENT 'Link to the contact table with uid=0 of the author of this item',
1131 `causer-id` int unsigned COMMENT 'Link to the contact table with uid=0 of the contact that caused the item creation',
1132 `post-type` tinyint unsigned NOT NULL DEFAULT 0 COMMENT 'Post type (personal note, image, article, ...)',
1133 `vid` smallint unsigned COMMENT 'Id of the verb table entry that contains the activity verbs',
1134 `private` tinyint unsigned NOT NULL DEFAULT 0 COMMENT '0=public, 1=private, 2=unlisted',
1135 `global` boolean NOT NULL DEFAULT '0' COMMENT '',
1136 `visible` boolean NOT NULL DEFAULT '0' COMMENT '',
1137 `deleted` boolean NOT NULL DEFAULT '0' COMMENT 'item has been marked for deletion',
1138 PRIMARY KEY(`uri-id`),
1139 INDEX `parent-uri-id` (`parent-uri-id`),
1140 INDEX `thr-parent-id` (`thr-parent-id`),
1141 INDEX `external-id` (`external-id`),
1142 INDEX `owner-id` (`owner-id`),
1143 INDEX `author-id` (`author-id`),
1144 INDEX `causer-id` (`causer-id`),
1145 INDEX `vid` (`vid`),
1146 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1147 FOREIGN KEY (`parent-uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1148 FOREIGN KEY (`thr-parent-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1149 FOREIGN KEY (`external-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1150 FOREIGN KEY (`owner-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT,
1151 FOREIGN KEY (`author-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT,
1152 FOREIGN KEY (`causer-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT,
1153 FOREIGN KEY (`vid`) REFERENCES `verb` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT
1154 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Structure for all posts';
1157 -- TABLE post-activity
1159 CREATE TABLE IF NOT EXISTS `post-activity` (
1160 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the item uri',
1161 `activity` mediumtext COMMENT 'Original activity',
1162 `received` datetime COMMENT '',
1163 PRIMARY KEY(`uri-id`),
1164 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
1165 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Original remote activity';
1168 -- TABLE post-category
1170 CREATE TABLE IF NOT EXISTS `post-category` (
1171 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the item uri',
1172 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'User id',
1173 `type` tinyint unsigned NOT NULL DEFAULT 0 COMMENT '',
1174 `tid` int unsigned NOT NULL DEFAULT 0 COMMENT '',
1175 PRIMARY KEY(`uri-id`,`uid`,`type`,`tid`),
1176 INDEX `tid` (`tid`),
1177 INDEX `uid_uri-id` (`uid`,`uri-id`),
1178 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1179 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE,
1180 FOREIGN KEY (`tid`) REFERENCES `tag` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT
1181 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='post relation to categories';
1184 -- TABLE post-collection
1186 CREATE TABLE IF NOT EXISTS `post-collection` (
1187 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the item uri',
1188 `type` tinyint unsigned NOT NULL DEFAULT 0 COMMENT '0 - Featured',
1189 `author-id` int unsigned COMMENT 'Author of the featured post',
1190 PRIMARY KEY(`uri-id`,`type`),
1191 INDEX `type` (`type`),
1192 INDEX `author-id` (`author-id`),
1193 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1194 FOREIGN KEY (`author-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
1195 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Collection of posts';
1198 -- TABLE post-content
1200 CREATE TABLE IF NOT EXISTS `post-content` (
1201 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the item uri',
1202 `title` varchar(255) NOT NULL DEFAULT '' COMMENT 'item title',
1203 `content-warning` varchar(255) NOT NULL DEFAULT '' COMMENT '',
1204 `body` mediumtext COMMENT 'item body content',
1205 `raw-body` mediumtext COMMENT 'Body without embedded media links',
1206 `quote-uri-id` int unsigned COMMENT 'Id of the item-uri table that contains the quoted uri',
1207 `location` varchar(255) NOT NULL DEFAULT '' COMMENT 'text location where this item originated',
1208 `coord` varchar(255) NOT NULL DEFAULT '' COMMENT 'longitude/latitude pair representing location where this item originated',
1209 `language` text COMMENT 'Language information about this post',
1210 `app` varchar(255) NOT NULL DEFAULT '' COMMENT 'application which generated this item',
1211 `rendered-hash` varchar(32) NOT NULL DEFAULT '' COMMENT '',
1212 `rendered-html` mediumtext COMMENT 'item.body converted to html',
1213 `object-type` varchar(100) NOT NULL DEFAULT '' COMMENT 'ActivityStreams object type',
1214 `object` text COMMENT 'JSON encoded object structure unless it is an implied object (normal post)',
1215 `target-type` varchar(100) NOT NULL DEFAULT '' COMMENT 'ActivityStreams target type if applicable (URI)',
1216 `target` text COMMENT 'JSON encoded target structure if used',
1217 `resource-id` varchar(32) NOT NULL DEFAULT '' COMMENT 'Used to link other tables to items, it identifies the linked resource (e.g. photo) and if set must also set resource_type',
1218 `plink` varbinary(383) NOT NULL DEFAULT '' COMMENT 'permalink or URL to a displayable copy of the message at its source',
1219 PRIMARY KEY(`uri-id`),
1220 INDEX `plink` (`plink`(191)),
1221 INDEX `resource-id` (`resource-id`),
1222 FULLTEXT INDEX `title-content-warning-body` (`title`,`content-warning`,`body`),
1223 INDEX `quote-uri-id` (`quote-uri-id`),
1224 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1225 FOREIGN KEY (`quote-uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
1226 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Content for all posts';
1229 -- TABLE post-delivery
1231 CREATE TABLE IF NOT EXISTS `post-delivery` (
1232 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the item uri',
1233 `inbox-id` int unsigned NOT NULL COMMENT 'Item-uri id of inbox url',
1234 `uid` mediumint unsigned COMMENT 'Delivering user',
1235 `created` datetime DEFAULT '0001-01-01 00:00:00' COMMENT '',
1236 `command` varbinary(32) COMMENT '',
1237 `failed` tinyint DEFAULT 0 COMMENT 'Number of times the delivery has failed',
1238 `receivers` mediumtext COMMENT 'JSON encoded array with the receiving contacts',
1239 PRIMARY KEY(`uri-id`,`inbox-id`),
1240 INDEX `inbox-id_created` (`inbox-id`,`created`),
1241 INDEX `uid` (`uid`),
1242 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1243 FOREIGN KEY (`inbox-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1244 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
1245 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Delivery data for posts for the batch processing';
1248 -- TABLE post-delivery-data
1250 CREATE TABLE IF NOT EXISTS `post-delivery-data` (
1251 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the item uri',
1252 `postopts` text COMMENT 'External post connectors add their network name to this comma-separated string to identify that they should be delivered to these networks during delivery',
1253 `inform` mediumtext COMMENT 'Additional receivers of the linked item',
1254 `queue_count` mediumint NOT NULL DEFAULT 0 COMMENT 'Initial number of delivery recipients, used as item.delivery_queue_count',
1255 `queue_done` mediumint NOT NULL DEFAULT 0 COMMENT 'Number of successful deliveries, used as item.delivery_queue_done',
1256 `queue_failed` mediumint NOT NULL DEFAULT 0 COMMENT 'Number of unsuccessful deliveries, used as item.delivery_queue_failed',
1257 `activitypub` mediumint NOT NULL DEFAULT 0 COMMENT 'Number of successful deliveries via ActivityPub',
1258 `dfrn` mediumint NOT NULL DEFAULT 0 COMMENT 'Number of successful deliveries via DFRN',
1259 `legacy_dfrn` mediumint NOT NULL DEFAULT 0 COMMENT 'Number of successful deliveries via legacy DFRN',
1260 `diaspora` mediumint NOT NULL DEFAULT 0 COMMENT 'Number of successful deliveries via Diaspora',
1261 `ostatus` mediumint NOT NULL DEFAULT 0 COMMENT 'Number of successful deliveries via OStatus',
1262 PRIMARY KEY(`uri-id`),
1263 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
1264 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Delivery data for items';
1267 -- TABLE post-history
1269 CREATE TABLE IF NOT EXISTS `post-history` (
1270 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the item uri',
1271 `edited` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Date of edit',
1272 `title` varchar(255) NOT NULL DEFAULT '' COMMENT 'item title',
1273 `content-warning` varchar(255) NOT NULL DEFAULT '' COMMENT '',
1274 `body` mediumtext COMMENT 'item body content',
1275 `raw-body` mediumtext COMMENT 'Body without embedded media links',
1276 `location` varchar(255) NOT NULL DEFAULT '' COMMENT 'text location where this item originated',
1277 `coord` varchar(255) NOT NULL DEFAULT '' COMMENT 'longitude/latitude pair representing location where this item originated',
1278 `language` text COMMENT 'Language information about this post',
1279 `app` varchar(255) NOT NULL DEFAULT '' COMMENT 'application which generated this item',
1280 `rendered-hash` varchar(32) NOT NULL DEFAULT '' COMMENT '',
1281 `rendered-html` mediumtext COMMENT 'item.body converted to html',
1282 `object-type` varchar(100) NOT NULL DEFAULT '' COMMENT 'ActivityStreams object type',
1283 `object` text COMMENT 'JSON encoded object structure unless it is an implied object (normal post)',
1284 `target-type` varchar(100) NOT NULL DEFAULT '' COMMENT 'ActivityStreams target type if applicable (URI)',
1285 `target` text COMMENT 'JSON encoded target structure if used',
1286 `resource-id` varchar(32) NOT NULL DEFAULT '' COMMENT 'Used to link other tables to items, it identifies the linked resource (e.g. photo) and if set must also set resource_type',
1287 `plink` varbinary(383) NOT NULL DEFAULT '' COMMENT 'permalink or URL to a displayable copy of the message at its source',
1288 PRIMARY KEY(`uri-id`,`edited`),
1289 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
1290 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Post history';
1295 CREATE TABLE IF NOT EXISTS `post-link` (
1296 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
1297 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the item uri',
1298 `url` varbinary(511) NOT NULL COMMENT 'External URL',
1299 `mimetype` varchar(60) COMMENT '',
1301 UNIQUE INDEX `uri-id-url` (`uri-id`,`url`),
1302 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
1303 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Post related external links';
1308 CREATE TABLE IF NOT EXISTS `post-media` (
1309 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
1310 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the item uri',
1311 `url` varbinary(1024) NOT NULL COMMENT 'Media URL',
1312 `media-uri-id` int unsigned COMMENT 'Id of the item-uri table entry that contains the activities uri-id',
1313 `type` tinyint unsigned NOT NULL DEFAULT 0 COMMENT 'Media type',
1314 `mimetype` varchar(60) COMMENT '',
1315 `height` smallint unsigned COMMENT 'Height of the media',
1316 `width` smallint unsigned COMMENT 'Width of the media',
1317 `size` bigint unsigned COMMENT 'Media size',
1318 `blurhash` varbinary(255) COMMENT 'BlurHash representation of the image',
1319 `preview` varbinary(512) COMMENT 'Preview URL',
1320 `preview-height` smallint unsigned COMMENT 'Height of the preview picture',
1321 `preview-width` smallint unsigned COMMENT 'Width of the preview picture',
1322 `description` text COMMENT '',
1323 `name` varchar(255) COMMENT 'Name of the media',
1324 `author-url` varbinary(383) COMMENT 'URL of the author of the media',
1325 `author-name` varchar(255) COMMENT 'Name of the author of the media',
1326 `author-image` varbinary(383) COMMENT 'Image of the author of the media',
1327 `publisher-url` varbinary(383) COMMENT 'URL of the publisher of the media',
1328 `publisher-name` varchar(255) COMMENT 'Name of the publisher of the media',
1329 `publisher-image` varbinary(383) COMMENT 'Image of the publisher of the media',
1331 UNIQUE INDEX `uri-id-url` (`uri-id`,`url`(512)),
1332 INDEX `uri-id-id` (`uri-id`,`id`),
1333 INDEX `media-uri-id` (`media-uri-id`),
1334 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1335 FOREIGN KEY (`media-uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
1336 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Attached media';
1339 -- TABLE post-question
1341 CREATE TABLE IF NOT EXISTS `post-question` (
1342 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
1343 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the item uri',
1344 `multiple` boolean NOT NULL DEFAULT '0' COMMENT 'Multiple choice',
1345 `voters` int unsigned COMMENT 'Number of voters for this question',
1346 `end-time` datetime DEFAULT '0001-01-01 00:00:00' COMMENT 'Question end time',
1348 UNIQUE INDEX `uri-id` (`uri-id`),
1349 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
1350 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Question';
1353 -- TABLE post-question-option
1355 CREATE TABLE IF NOT EXISTS `post-question-option` (
1356 `id` int unsigned NOT NULL COMMENT 'Id of the question',
1357 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the item uri',
1358 `name` varchar(255) COMMENT 'Name of the option',
1359 `replies` int unsigned COMMENT 'Number of replies for this question option',
1360 PRIMARY KEY(`uri-id`,`id`),
1361 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
1362 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Question option';
1367 CREATE TABLE IF NOT EXISTS `post-tag` (
1368 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the item uri',
1369 `type` tinyint unsigned NOT NULL DEFAULT 0 COMMENT '',
1370 `tid` int unsigned NOT NULL DEFAULT 0 COMMENT '',
1371 `cid` int unsigned NOT NULL DEFAULT 0 COMMENT 'Contact id of the mentioned public contact',
1372 PRIMARY KEY(`uri-id`,`type`,`tid`,`cid`),
1373 INDEX `tid` (`tid`),
1374 INDEX `cid` (`cid`),
1375 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1376 FOREIGN KEY (`tid`) REFERENCES `tag` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT,
1377 FOREIGN KEY (`cid`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT
1378 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='post relation to tags';
1381 -- TABLE post-thread
1383 CREATE TABLE IF NOT EXISTS `post-thread` (
1384 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the item uri',
1385 `conversation-id` int unsigned COMMENT 'Id of the item-uri table entry that contains the conversation uri',
1386 `owner-id` int unsigned NOT NULL DEFAULT 0 COMMENT 'Item owner',
1387 `author-id` int unsigned NOT NULL DEFAULT 0 COMMENT 'Item author',
1388 `causer-id` int unsigned COMMENT 'Link to the contact table with uid=0 of the contact that caused the item creation',
1389 `network` char(4) NOT NULL DEFAULT '' COMMENT '',
1390 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
1391 `received` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
1392 `changed` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Date that something in the conversation changed, indicating clients should fetch the conversation again',
1393 `commented` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
1394 PRIMARY KEY(`uri-id`),
1395 INDEX `conversation-id` (`conversation-id`),
1396 INDEX `owner-id` (`owner-id`),
1397 INDEX `author-id` (`author-id`),
1398 INDEX `causer-id` (`causer-id`),
1399 INDEX `received` (`received`),
1400 INDEX `commented` (`commented`),
1401 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1402 FOREIGN KEY (`conversation-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1403 FOREIGN KEY (`owner-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT,
1404 FOREIGN KEY (`author-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT,
1405 FOREIGN KEY (`causer-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT
1406 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Thread related data';
1411 CREATE TABLE IF NOT EXISTS `post-user` (
1412 `id` int unsigned NOT NULL auto_increment,
1413 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the item uri',
1414 `parent-uri-id` int unsigned COMMENT 'Id of the item-uri table that contains the parent uri',
1415 `thr-parent-id` int unsigned COMMENT 'Id of the item-uri table that contains the thread parent uri',
1416 `external-id` int unsigned COMMENT 'Id of the item-uri table entry that contains the external uri',
1417 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Creation timestamp.',
1418 `edited` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Date of last edit (default is created)',
1419 `received` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'datetime',
1420 `gravity` tinyint unsigned NOT NULL DEFAULT 0 COMMENT '',
1421 `network` char(4) NOT NULL DEFAULT '' COMMENT 'Network from where the item comes from',
1422 `owner-id` int unsigned NOT NULL DEFAULT 0 COMMENT 'Link to the contact table with uid=0 of the owner of this item',
1423 `author-id` int unsigned NOT NULL DEFAULT 0 COMMENT 'Link to the contact table with uid=0 of the author of this item',
1424 `causer-id` int unsigned COMMENT 'Link to the contact table with uid=0 of the contact that caused the item creation',
1425 `post-type` tinyint unsigned NOT NULL DEFAULT 0 COMMENT 'Post type (personal note, image, article, ...)',
1426 `post-reason` tinyint unsigned NOT NULL DEFAULT 0 COMMENT 'Reason why the post arrived at the user',
1427 `vid` smallint unsigned COMMENT 'Id of the verb table entry that contains the activity verbs',
1428 `private` tinyint unsigned NOT NULL DEFAULT 0 COMMENT '0=public, 1=private, 2=unlisted',
1429 `global` boolean NOT NULL DEFAULT '0' COMMENT '',
1430 `visible` boolean NOT NULL DEFAULT '0' COMMENT '',
1431 `deleted` boolean NOT NULL DEFAULT '0' COMMENT 'item has been marked for deletion',
1432 `uid` mediumint unsigned NOT NULL COMMENT 'Owner id which owns this copy of the item',
1433 `protocol` tinyint unsigned COMMENT 'Protocol used to deliver the item for this user',
1434 `contact-id` int unsigned NOT NULL DEFAULT 0 COMMENT 'contact.id',
1435 `event-id` int unsigned COMMENT 'Used to link to the event.id',
1436 `unseen` boolean NOT NULL DEFAULT '1' COMMENT 'post has not been seen',
1437 `hidden` boolean NOT NULL DEFAULT '0' COMMENT 'Marker to hide the post from the user',
1438 `notification-type` tinyint unsigned NOT NULL DEFAULT 0 COMMENT '',
1439 `wall` boolean NOT NULL DEFAULT '0' COMMENT 'This item was posted to the wall of uid',
1440 `origin` boolean NOT NULL DEFAULT '0' COMMENT 'item originated at this site',
1441 `psid` int unsigned COMMENT 'ID of the permission set of this post',
1443 UNIQUE INDEX `uid_uri-id` (`uid`,`uri-id`),
1444 INDEX `uri-id` (`uri-id`),
1445 INDEX `parent-uri-id` (`parent-uri-id`),
1446 INDEX `thr-parent-id` (`thr-parent-id`),
1447 INDEX `external-id` (`external-id`),
1448 INDEX `owner-id` (`owner-id`),
1449 INDEX `author-id` (`author-id`),
1450 INDEX `causer-id` (`causer-id`),
1451 INDEX `vid` (`vid`),
1452 INDEX `contact-id` (`contact-id`),
1453 INDEX `event-id` (`event-id`),
1454 INDEX `psid` (`psid`),
1455 INDEX `author-id_uid` (`author-id`,`uid`),
1456 INDEX `author-id_received` (`author-id`,`received`),
1457 INDEX `parent-uri-id_uid` (`parent-uri-id`,`uid`),
1458 INDEX `uid_wall_received` (`uid`,`wall`,`received`),
1459 INDEX `uid_contactid` (`uid`,`contact-id`),
1460 INDEX `uid_unseen_contactid` (`uid`,`unseen`,`contact-id`),
1461 INDEX `uid_unseen` (`uid`,`unseen`),
1462 INDEX `uid_hidden_uri-id` (`uid`,`hidden`,`uri-id`),
1463 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1464 FOREIGN KEY (`parent-uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1465 FOREIGN KEY (`thr-parent-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1466 FOREIGN KEY (`external-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1467 FOREIGN KEY (`owner-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT,
1468 FOREIGN KEY (`author-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT,
1469 FOREIGN KEY (`causer-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT,
1470 FOREIGN KEY (`vid`) REFERENCES `verb` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT,
1471 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE,
1472 FOREIGN KEY (`contact-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1473 FOREIGN KEY (`event-id`) REFERENCES `event` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1474 FOREIGN KEY (`psid`) REFERENCES `permissionset` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT
1475 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='User specific post data';
1478 -- TABLE post-thread-user
1480 CREATE TABLE IF NOT EXISTS `post-thread-user` (
1481 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the item uri',
1482 `conversation-id` int unsigned COMMENT 'Id of the item-uri table entry that contains the conversation uri',
1483 `owner-id` int unsigned NOT NULL DEFAULT 0 COMMENT 'Item owner',
1484 `author-id` int unsigned NOT NULL DEFAULT 0 COMMENT 'Item author',
1485 `causer-id` int unsigned COMMENT 'Link to the contact table with uid=0 of the contact that caused the item creation',
1486 `network` char(4) NOT NULL DEFAULT '' COMMENT '',
1487 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
1488 `received` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
1489 `changed` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Date that something in the conversation changed, indicating clients should fetch the conversation again',
1490 `commented` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
1491 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'Owner id which owns this copy of the item',
1492 `pinned` boolean NOT NULL DEFAULT '0' COMMENT 'deprecated',
1493 `starred` boolean NOT NULL DEFAULT '0' COMMENT '',
1494 `ignored` boolean NOT NULL DEFAULT '0' COMMENT 'Ignore updates for this thread',
1495 `wall` boolean NOT NULL DEFAULT '0' COMMENT 'This item was posted to the wall of uid',
1496 `mention` boolean NOT NULL DEFAULT '0' COMMENT '',
1497 `pubmail` boolean NOT NULL DEFAULT '0' COMMENT '',
1498 `forum_mode` tinyint unsigned NOT NULL DEFAULT 0 COMMENT 'Deprecated',
1499 `contact-id` int unsigned NOT NULL DEFAULT 0 COMMENT 'contact.id',
1500 `unseen` boolean NOT NULL DEFAULT '1' COMMENT 'post has not been seen',
1501 `hidden` boolean NOT NULL DEFAULT '0' COMMENT 'Marker to hide the post from the user',
1502 `origin` boolean NOT NULL DEFAULT '0' COMMENT 'item originated at this site',
1503 `psid` int unsigned COMMENT 'ID of the permission set of this post',
1504 `post-user-id` int unsigned COMMENT 'Id of the post-user table',
1505 PRIMARY KEY(`uid`,`uri-id`),
1506 INDEX `uri-id` (`uri-id`),
1507 INDEX `conversation-id` (`conversation-id`),
1508 INDEX `owner-id` (`owner-id`),
1509 INDEX `author-id` (`author-id`),
1510 INDEX `causer-id` (`causer-id`),
1511 INDEX `uid` (`uid`),
1512 INDEX `contact-id` (`contact-id`),
1513 INDEX `psid` (`psid`),
1514 INDEX `post-user-id` (`post-user-id`),
1515 INDEX `commented` (`commented`),
1516 INDEX `uid_received` (`uid`,`received`),
1517 INDEX `uid_wall_received` (`uid`,`wall`,`received`),
1518 INDEX `uid_commented` (`uid`,`commented`),
1519 INDEX `uid_starred` (`uid`,`starred`),
1520 INDEX `uid_mention` (`uid`,`mention`),
1521 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1522 FOREIGN KEY (`conversation-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1523 FOREIGN KEY (`owner-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT,
1524 FOREIGN KEY (`author-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT,
1525 FOREIGN KEY (`causer-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT,
1526 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE,
1527 FOREIGN KEY (`contact-id`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1528 FOREIGN KEY (`psid`) REFERENCES `permissionset` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT,
1529 FOREIGN KEY (`post-user-id`) REFERENCES `post-user` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
1530 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Thread related data per user';
1533 -- TABLE post-user-notification
1535 CREATE TABLE IF NOT EXISTS `post-user-notification` (
1536 `uri-id` int unsigned NOT NULL COMMENT 'Id of the item-uri table entry that contains the item uri',
1537 `uid` mediumint unsigned NOT NULL COMMENT 'Owner id which owns this copy of the item',
1538 `notification-type` smallint unsigned NOT NULL DEFAULT 0 COMMENT '',
1539 PRIMARY KEY(`uid`,`uri-id`),
1540 INDEX `uri-id` (`uri-id`),
1541 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1542 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
1543 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='User post notifications';
1548 CREATE TABLE IF NOT EXISTS `process` (
1549 `pid` int unsigned NOT NULL COMMENT 'The ID of the process',
1550 `hostname` varchar(32) NOT NULL COMMENT 'The name of the host the process is ran on',
1551 `command` varbinary(32) NOT NULL DEFAULT '' COMMENT '',
1552 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
1553 PRIMARY KEY(`pid`,`hostname`),
1554 INDEX `command` (`command`)
1555 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Currently running system processes';
1560 CREATE TABLE IF NOT EXISTS `profile` (
1561 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
1562 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'Owner User id',
1563 `profile-name` varchar(255) COMMENT 'Deprecated',
1564 `is-default` boolean COMMENT 'Deprecated',
1565 `hide-friends` boolean NOT NULL DEFAULT '0' COMMENT 'Hide friend list from viewers of this profile',
1566 `name` varchar(255) NOT NULL DEFAULT '' COMMENT '',
1567 `pdesc` varchar(255) COMMENT 'Deprecated',
1568 `dob` varchar(32) NOT NULL DEFAULT '0000-00-00' COMMENT 'Day of birth',
1569 `address` varchar(255) NOT NULL DEFAULT '' COMMENT '',
1570 `locality` varchar(255) NOT NULL DEFAULT '' COMMENT '',
1571 `region` varchar(255) NOT NULL DEFAULT '' COMMENT '',
1572 `postal-code` varchar(32) NOT NULL DEFAULT '' COMMENT '',
1573 `country-name` varchar(255) NOT NULL DEFAULT '' COMMENT '',
1574 `hometown` varchar(255) COMMENT 'Deprecated',
1575 `gender` varchar(32) COMMENT 'Deprecated',
1576 `marital` varchar(255) COMMENT 'Deprecated',
1577 `with` text COMMENT 'Deprecated',
1578 `howlong` datetime COMMENT 'Deprecated',
1579 `sexual` varchar(255) COMMENT 'Deprecated',
1580 `politic` varchar(255) COMMENT 'Deprecated',
1581 `religion` varchar(255) COMMENT 'Deprecated',
1582 `pub_keywords` text COMMENT '',
1583 `prv_keywords` text COMMENT '',
1584 `likes` text COMMENT 'Deprecated',
1585 `dislikes` text COMMENT 'Deprecated',
1586 `about` text COMMENT 'Profile description',
1587 `summary` varchar(255) COMMENT 'Deprecated',
1588 `music` text COMMENT 'Deprecated',
1589 `book` text COMMENT 'Deprecated',
1590 `tv` text COMMENT 'Deprecated',
1591 `film` text COMMENT 'Deprecated',
1592 `interest` text COMMENT 'Deprecated',
1593 `romance` text COMMENT 'Deprecated',
1594 `work` text COMMENT 'Deprecated',
1595 `education` text COMMENT 'Deprecated',
1596 `contact` text COMMENT 'Deprecated',
1597 `homepage` varchar(255) NOT NULL DEFAULT '' COMMENT '',
1598 `homepage_verified` boolean NOT NULL DEFAULT '0' COMMENT 'was the homepage verified by a rel-me link back to the profile',
1599 `xmpp` varchar(255) NOT NULL DEFAULT '' COMMENT 'XMPP address',
1600 `matrix` varchar(255) NOT NULL DEFAULT '' COMMENT 'Matrix address',
1601 `photo` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
1602 `thumb` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
1603 `publish` boolean NOT NULL DEFAULT '0' COMMENT 'publish default profile in local directory',
1604 `net-publish` boolean NOT NULL DEFAULT '0' COMMENT 'publish profile in global directory',
1606 INDEX `uid_is-default` (`uid`,`is-default`),
1607 FULLTEXT INDEX `pub_keywords` (`pub_keywords`),
1608 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
1609 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='user profiles data';
1612 -- TABLE profile_field
1614 CREATE TABLE IF NOT EXISTS `profile_field` (
1615 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
1616 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'Owner user id',
1617 `order` mediumint unsigned NOT NULL DEFAULT 1 COMMENT 'Field ordering per user',
1618 `psid` int unsigned COMMENT 'ID of the permission set of this profile field - 0 = public',
1619 `label` varchar(255) NOT NULL DEFAULT '' COMMENT 'Label of the field',
1620 `value` text COMMENT 'Value of the field',
1621 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'creation time',
1622 `edited` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'last edit time',
1624 INDEX `uid` (`uid`),
1625 INDEX `order` (`order`),
1626 INDEX `psid` (`psid`),
1627 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE,
1628 FOREIGN KEY (`psid`) REFERENCES `permissionset` (`id`) ON UPDATE RESTRICT ON DELETE RESTRICT
1629 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Custom profile fields';
1632 -- TABLE push_subscriber
1634 CREATE TABLE IF NOT EXISTS `push_subscriber` (
1635 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
1636 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'User id',
1637 `callback_url` varbinary(383) NOT NULL DEFAULT '' COMMENT '',
1638 `topic` varchar(255) NOT NULL DEFAULT '' COMMENT '',
1639 `nickname` varchar(255) NOT NULL DEFAULT '' COMMENT '',
1640 `push` tinyint NOT NULL DEFAULT 0 COMMENT 'Retrial counter',
1641 `last_update` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Date of last successful trial',
1642 `next_try` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Next retrial date',
1643 `renewed` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT 'Date of last subscription renewal',
1644 `secret` varchar(255) NOT NULL DEFAULT '' COMMENT '',
1646 INDEX `next_try` (`next_try`),
1647 INDEX `uid` (`uid`),
1648 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
1649 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Used for OStatus: Contains feed subscribers';
1654 CREATE TABLE IF NOT EXISTS `register` (
1655 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
1656 `hash` varbinary(255) NOT NULL DEFAULT '' COMMENT '',
1657 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
1658 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'User id',
1659 `password` varchar(255) NOT NULL DEFAULT '' COMMENT '',
1660 `language` varchar(16) NOT NULL DEFAULT '' COMMENT '',
1661 `note` text COMMENT '',
1663 INDEX `uid` (`uid`),
1664 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
1665 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='registrations requiring admin approval';
1670 CREATE TABLE IF NOT EXISTS `report` (
1671 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
1672 `uid` mediumint unsigned COMMENT 'Reporting user',
1673 `cid` int unsigned NOT NULL COMMENT 'Reported contact',
1674 `comment` text COMMENT 'Report',
1675 `forward` boolean COMMENT 'Forward the report to the remote server',
1676 `created` datetime NOT NULL DEFAULT '0001-01-01 00:00:00' COMMENT '',
1677 `status` tinyint unsigned COMMENT 'Status of the report',
1679 INDEX `uid` (`uid`),
1680 INDEX `cid` (`cid`),
1681 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE,
1682 FOREIGN KEY (`cid`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
1683 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='';
1686 -- TABLE report-post
1688 CREATE TABLE IF NOT EXISTS `report-post` (
1689 `rid` int unsigned NOT NULL COMMENT 'Report id',
1690 `uri-id` int unsigned NOT NULL COMMENT 'Uri-id of the reported post',
1691 `status` tinyint unsigned COMMENT 'Status of the reported post',
1692 PRIMARY KEY(`rid`,`uri-id`),
1693 INDEX `uri-id` (`uri-id`),
1694 FOREIGN KEY (`rid`) REFERENCES `report` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1695 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
1696 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='';
1701 CREATE TABLE IF NOT EXISTS `search` (
1702 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
1703 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'User id',
1704 `term` varchar(255) NOT NULL DEFAULT '' COMMENT '',
1706 INDEX `uid_term` (`uid`,`term`(64)),
1707 INDEX `term` (`term`(64)),
1708 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
1709 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='';
1714 CREATE TABLE IF NOT EXISTS `session` (
1715 `id` bigint unsigned NOT NULL auto_increment COMMENT 'sequential ID',
1716 `sid` varbinary(255) NOT NULL DEFAULT '' COMMENT '',
1717 `data` text COMMENT '',
1718 `expire` int unsigned NOT NULL DEFAULT 0 COMMENT '',
1720 INDEX `sid` (`sid`(64)),
1721 INDEX `expire` (`expire`)
1722 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='web session storage';
1727 CREATE TABLE IF NOT EXISTS `storage` (
1728 `id` int unsigned NOT NULL auto_increment COMMENT 'Auto incremented image data id',
1729 `data` longblob NOT NULL COMMENT 'file data',
1731 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Data stored by Database storage backend';
1734 -- TABLE subscription
1736 CREATE TABLE IF NOT EXISTS `subscription` (
1737 `id` int unsigned NOT NULL auto_increment COMMENT 'Auto incremented image data id',
1738 `application-id` int unsigned NOT NULL COMMENT '',
1739 `uid` mediumint unsigned NOT NULL COMMENT 'Owner User id',
1740 `endpoint` varchar(511) COMMENT 'Endpoint URL',
1741 `pubkey` varchar(127) COMMENT 'User agent public key',
1742 `secret` varchar(32) COMMENT 'Auth secret',
1743 `follow` boolean COMMENT '',
1744 `favourite` boolean COMMENT '',
1745 `reblog` boolean COMMENT '',
1746 `mention` boolean COMMENT '',
1747 `poll` boolean COMMENT '',
1748 `follow_request` boolean COMMENT '',
1749 `status` boolean COMMENT '',
1751 UNIQUE INDEX `application-id_uid` (`application-id`,`uid`),
1752 INDEX `uid_application-id` (`uid`,`application-id`),
1753 FOREIGN KEY (`application-id`) REFERENCES `application` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1754 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE
1755 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Push Subscription for the API';
1760 CREATE TABLE IF NOT EXISTS `userd` (
1761 `id` int unsigned NOT NULL auto_increment COMMENT 'sequential ID',
1762 `username` varchar(255) NOT NULL COMMENT '',
1764 INDEX `username` (`username`(32))
1765 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='Deleted usernames';
1768 -- TABLE user-contact
1770 CREATE TABLE IF NOT EXISTS `user-contact` (
1771 `cid` int unsigned NOT NULL DEFAULT 0 COMMENT 'Contact id of the linked public contact',
1772 `uid` mediumint unsigned NOT NULL DEFAULT 0 COMMENT 'User id',
1773 `uri-id` int unsigned COMMENT 'Id of the item-uri table entry that contains the contact url',
1774 `blocked` boolean COMMENT 'Contact is completely blocked for this user',
1775 `ignored` boolean COMMENT 'Posts from this contact are ignored',
1776 `collapsed` boolean COMMENT 'Posts from this contact are collapsed',
1777 `hidden` boolean COMMENT 'This contact is hidden from the others',
1778 `is-blocked` boolean COMMENT 'User is blocked by this contact',
1779 `pending` boolean COMMENT '',
1780 `rel` tinyint unsigned COMMENT 'The kind of the relation between the user and the contact',
1781 `info` mediumtext COMMENT '',
1782 `notify_new_posts` boolean COMMENT '',
1783 `remote_self` boolean COMMENT '',
1784 `fetch_further_information` tinyint unsigned COMMENT '',
1785 `ffi_keyword_denylist` text COMMENT '',
1786 `subhub` boolean COMMENT '',
1787 `hub-verify` varbinary(383) COMMENT '',
1788 `protocol` char(4) COMMENT 'Protocol of the contact',
1789 `rating` tinyint COMMENT 'Automatically detected feed poll frequency',
1790 `priority` tinyint unsigned COMMENT 'Feed poll priority',
1791 PRIMARY KEY(`uid`,`cid`),
1792 INDEX `cid` (`cid`),
1793 UNIQUE INDEX `uri-id_uid` (`uri-id`,`uid`),
1794 FOREIGN KEY (`cid`) REFERENCES `contact` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE,
1795 FOREIGN KEY (`uid`) REFERENCES `user` (`uid`) ON UPDATE RESTRICT ON DELETE CASCADE,
1796 FOREIGN KEY (`uri-id`) REFERENCES `item-uri` (`id`) ON UPDATE RESTRICT ON DELETE CASCADE
1797 ) DEFAULT COLLATE utf8mb4_general_ci COMMENT='User specific public contact data';
1800 -- TABLE arrived-activity
1802 CREATE TABLE IF NOT EXISTS `arrived-activity` (
1803 `object-id` varbinary(383) NOT NULL COMMENT 'object id of the incoming activity',
1804 `received` datetime COMMENT 'Receiving date',
1805 PRIMARY KEY(`object-id`)
1806 ) ENGINE=MEMORY DEFAULT COLLATE utf8mb4_general_ci COMMENT='Id of arrived activities';
1809 -- TABLE fetched-activity
1811 CREATE TABLE IF NOT EXISTS `fetched-activity` (
1812 `object-id` varbinary(383) NOT NULL COMMENT 'object id of fetched activity',
1813 `received` datetime COMMENT 'Receiving date',
1814 PRIMARY KEY(`object-id`)
1815 ) ENGINE=MEMORY DEFAULT COLLATE utf8mb4_general_ci COMMENT='Id of fetched activities';
1820 CREATE TABLE IF NOT EXISTS `worker-ipc` (
1821 `key` int NOT NULL COMMENT '',
1822 `jobs` boolean COMMENT 'Flag for outstanding jobs',
1824 ) ENGINE=MEMORY DEFAULT COLLATE utf8mb4_general_ci COMMENT='Inter process communication between the frontend and the worker';
1827 -- VIEW application-view
1829 DROP VIEW IF EXISTS `application-view`;
1830 CREATE VIEW `application-view` AS SELECT
1831 `application`.`id` AS `id`,
1832 `application-token`.`uid` AS `uid`,
1833 `application`.`name` AS `name`,
1834 `application`.`redirect_uri` AS `redirect_uri`,
1835 `application`.`website` AS `website`,
1836 `application`.`client_id` AS `client_id`,
1837 `application`.`client_secret` AS `client_secret`,
1838 `application-token`.`code` AS `code`,
1839 `application-token`.`access_token` AS `access_token`,
1840 `application-token`.`created_at` AS `created_at`,
1841 `application-token`.`scopes` AS `scopes`,
1842 `application-token`.`read` AS `read`,
1843 `application-token`.`write` AS `write`,
1844 `application-token`.`follow` AS `follow`,
1845 `application-token`.`push` AS `push`
1846 FROM `application-token`
1847 INNER JOIN `application` ON `application-token`.`application-id` = `application`.`id`;
1850 -- VIEW post-user-view
1852 DROP VIEW IF EXISTS `post-user-view`;
1853 CREATE VIEW `post-user-view` AS SELECT
1854 `post-user`.`id` AS `id`,
1855 `post-user`.`id` AS `post-user-id`,
1856 `post-user`.`uid` AS `uid`,
1857 `parent-post`.`id` AS `parent`,
1858 `item-uri`.`uri` AS `uri`,
1859 `post-user`.`uri-id` AS `uri-id`,
1860 `parent-item-uri`.`uri` AS `parent-uri`,
1861 `post-user`.`parent-uri-id` AS `parent-uri-id`,
1862 `thr-parent-item-uri`.`uri` AS `thr-parent`,
1863 `post-user`.`thr-parent-id` AS `thr-parent-id`,
1864 `conversation-item-uri`.`uri` AS `conversation`,
1865 `post-thread-user`.`conversation-id` AS `conversation-id`,
1866 `quote-item-uri`.`uri` AS `quote-uri`,
1867 `post-content`.`quote-uri-id` AS `quote-uri-id`,
1868 `item-uri`.`guid` AS `guid`,
1869 `post-user`.`wall` AS `wall`,
1870 `post-user`.`gravity` AS `gravity`,
1871 `external-item-uri`.`uri` AS `extid`,
1872 `post-user`.`external-id` AS `external-id`,
1873 `post-user`.`created` AS `created`,
1874 `post-user`.`edited` AS `edited`,
1875 `post-thread-user`.`commented` AS `commented`,
1876 `post-user`.`received` AS `received`,
1877 `post-thread-user`.`changed` AS `changed`,
1878 `post-user`.`post-type` AS `post-type`,
1879 `post-user`.`post-reason` AS `post-reason`,
1880 `post-user`.`private` AS `private`,
1881 `post-thread-user`.`pubmail` AS `pubmail`,
1882 `post-user`.`visible` AS `visible`,
1883 `post-thread-user`.`starred` AS `starred`,
1884 `post-user`.`unseen` AS `unseen`,
1885 `post-user`.`deleted` AS `deleted`,
1886 `post-user`.`origin` AS `origin`,
1887 `post-thread-user`.`origin` AS `parent-origin`,
1888 `post-thread-user`.`mention` AS `mention`,
1889 `post-user`.`global` AS `global`,
1890 EXISTS(SELECT `type` FROM `post-collection` WHERE `type` = 0 AND `uri-id` = `post-user`.`uri-id`) AS `featured`,
1891 `post-user`.`network` AS `network`,
1892 `post-user`.`protocol` AS `protocol`,
1893 `post-user`.`vid` AS `vid`,
1894 `post-user`.`psid` AS `psid`,
1895 IF (`post-user`.`vid` IS NULL, '', `verb`.`name`) AS `verb`,
1896 `post-content`.`title` AS `title`,
1897 `post-content`.`content-warning` AS `content-warning`,
1898 `post-content`.`raw-body` AS `raw-body`,
1899 IFNULL (`post-content`.`body`, '') AS `body`,
1900 `post-content`.`rendered-hash` AS `rendered-hash`,
1901 `post-content`.`rendered-html` AS `rendered-html`,
1902 `post-content`.`language` AS `language`,
1903 `post-content`.`plink` AS `plink`,
1904 `post-content`.`location` AS `location`,
1905 `post-content`.`coord` AS `coord`,
1906 `post-content`.`app` AS `app`,
1907 `post-content`.`object-type` AS `object-type`,
1908 `post-content`.`object` AS `object`,
1909 `post-content`.`target-type` AS `target-type`,
1910 `post-content`.`target` AS `target`,
1911 `post-content`.`resource-id` AS `resource-id`,
1912 `post-user`.`contact-id` AS `contact-id`,
1913 `contact`.`uri-id` AS `contact-uri-id`,
1914 `contact`.`url` AS `contact-link`,
1915 `contact`.`addr` AS `contact-addr`,
1916 `contact`.`name` AS `contact-name`,
1917 `contact`.`nick` AS `contact-nick`,
1918 `contact`.`thumb` AS `contact-avatar`,
1919 `contact`.`network` AS `contact-network`,
1920 `contact`.`blocked` AS `contact-blocked`,
1921 `contact`.`hidden` AS `contact-hidden`,
1922 `contact`.`readonly` AS `contact-readonly`,
1923 `contact`.`archive` AS `contact-archive`,
1924 `contact`.`pending` AS `contact-pending`,
1925 `contact`.`rel` AS `contact-rel`,
1926 `contact`.`uid` AS `contact-uid`,
1927 `contact`.`contact-type` AS `contact-contact-type`,
1928 IF (`post-user`.`network` IN ('apub', 'dfrn', 'dspr', 'stat'), true, `contact`.`writable`) AS `writable`,
1929 `contact`.`self` AS `self`,
1930 `contact`.`id` AS `cid`,
1931 `contact`.`alias` AS `alias`,
1932 `contact`.`photo` AS `photo`,
1933 `contact`.`name-date` AS `name-date`,
1934 `contact`.`uri-date` AS `uri-date`,
1935 `contact`.`avatar-date` AS `avatar-date`,
1936 `contact`.`thumb` AS `thumb`,
1937 `post-user`.`author-id` AS `author-id`,
1938 `author`.`uri-id` AS `author-uri-id`,
1939 `author`.`url` AS `author-link`,
1940 `author`.`addr` AS `author-addr`,
1941 IF (`contact`.`url` = `author`.`url` AND `contact`.`name` != '', `contact`.`name`, `author`.`name`) AS `author-name`,
1942 `author`.`nick` AS `author-nick`,
1943 IF (`contact`.`url` = `author`.`url` AND `contact`.`thumb` != '', `contact`.`thumb`, `author`.`thumb`) AS `author-avatar`,
1944 `author`.`network` AS `author-network`,
1945 `author`.`blocked` AS `author-blocked`,
1946 `author`.`hidden` AS `author-hidden`,
1947 `author`.`updated` AS `author-updated`,
1948 `author`.`gsid` AS `author-gsid`,
1949 `post-user`.`owner-id` AS `owner-id`,
1950 `owner`.`uri-id` AS `owner-uri-id`,
1951 `owner`.`url` AS `owner-link`,
1952 `owner`.`addr` AS `owner-addr`,
1953 IF (`contact`.`url` = `owner`.`url` AND `contact`.`name` != '', `contact`.`name`, `owner`.`name`) AS `owner-name`,
1954 `owner`.`nick` AS `owner-nick`,
1955 IF (`contact`.`url` = `owner`.`url` AND `contact`.`thumb` != '', `contact`.`thumb`, `owner`.`thumb`) AS `owner-avatar`,
1956 `owner`.`network` AS `owner-network`,
1957 `owner`.`blocked` AS `owner-blocked`,
1958 `owner`.`hidden` AS `owner-hidden`,
1959 `owner`.`updated` AS `owner-updated`,
1960 `owner`.`contact-type` AS `owner-contact-type`,
1961 `post-user`.`causer-id` AS `causer-id`,
1962 `causer`.`uri-id` AS `causer-uri-id`,
1963 `causer`.`url` AS `causer-link`,
1964 `causer`.`addr` AS `causer-addr`,
1965 `causer`.`name` AS `causer-name`,
1966 `causer`.`nick` AS `causer-nick`,
1967 `causer`.`thumb` AS `causer-avatar`,
1968 `causer`.`network` AS `causer-network`,
1969 `causer`.`blocked` AS `causer-blocked`,
1970 `causer`.`hidden` AS `causer-hidden`,
1971 `causer`.`contact-type` AS `causer-contact-type`,
1972 `post-delivery-data`.`postopts` AS `postopts`,
1973 `post-delivery-data`.`inform` AS `inform`,
1974 `post-delivery-data`.`queue_count` AS `delivery_queue_count`,
1975 `post-delivery-data`.`queue_done` AS `delivery_queue_done`,
1976 `post-delivery-data`.`queue_failed` AS `delivery_queue_failed`,
1977 IF (`post-user`.`psid` IS NULL, '', `permissionset`.`allow_cid`) AS `allow_cid`,
1978 IF (`post-user`.`psid` IS NULL, '', `permissionset`.`allow_gid`) AS `allow_gid`,
1979 IF (`post-user`.`psid` IS NULL, '', `permissionset`.`deny_cid`) AS `deny_cid`,
1980 IF (`post-user`.`psid` IS NULL, '', `permissionset`.`deny_gid`) AS `deny_gid`,
1981 `post-user`.`event-id` AS `event-id`,
1982 `event`.`created` AS `event-created`,
1983 `event`.`edited` AS `event-edited`,
1984 `event`.`start` AS `event-start`,
1985 `event`.`finish` AS `event-finish`,
1986 `event`.`summary` AS `event-summary`,
1987 `event`.`desc` AS `event-desc`,
1988 `event`.`location` AS `event-location`,
1989 `event`.`type` AS `event-type`,
1990 `event`.`nofinish` AS `event-nofinish`,
1991 `event`.`ignore` AS `event-ignore`,
1992 `post-question`.`id` AS `question-id`,
1993 `post-question`.`multiple` AS `question-multiple`,
1994 `post-question`.`voters` AS `question-voters`,
1995 `post-question`.`end-time` AS `question-end-time`,
1996 EXISTS(SELECT `uri-id` FROM `post-category` WHERE `post-category`.`uri-id` = `post-user`.`uri-id` AND `post-category`.`uid` = `post-user`.`uid`) AS `has-categories`,
1997 EXISTS(SELECT `id` FROM `post-media` WHERE `post-media`.`uri-id` = `post-user`.`uri-id`) AS `has-media`,
1998 `diaspora-interaction`.`interaction` AS `signed_text`,
1999 `parent-item-uri`.`guid` AS `parent-guid`,
2000 `parent-post`.`network` AS `parent-network`,
2001 `parent-post`.`author-id` AS `parent-author-id`,
2002 `parent-post-author`.`url` AS `parent-author-link`,
2003 `parent-post-author`.`name` AS `parent-author-name`,
2004 `parent-post-author`.`nick` AS `parent-author-nick`,
2005 `parent-post-author`.`network` AS `parent-author-network`
2007 STRAIGHT_JOIN `post-thread-user` ON `post-thread-user`.`uri-id` = `post-user`.`parent-uri-id` AND `post-thread-user`.`uid` = `post-user`.`uid`
2008 STRAIGHT_JOIN `contact` ON `contact`.`id` = `post-user`.`contact-id`
2009 STRAIGHT_JOIN `contact` AS `author` ON `author`.`id` = `post-user`.`author-id`
2010 STRAIGHT_JOIN `contact` AS `owner` ON `owner`.`id` = `post-user`.`owner-id`
2011 LEFT JOIN `contact` AS `causer` ON `causer`.`id` = `post-user`.`causer-id`
2012 LEFT JOIN `item-uri` ON `item-uri`.`id` = `post-user`.`uri-id`
2013 LEFT JOIN `item-uri` AS `thr-parent-item-uri` ON `thr-parent-item-uri`.`id` = `post-user`.`thr-parent-id`
2014 LEFT JOIN `item-uri` AS `parent-item-uri` ON `parent-item-uri`.`id` = `post-user`.`parent-uri-id`
2015 LEFT JOIN `item-uri` AS `conversation-item-uri` ON `conversation-item-uri`.`id` = `post-thread-user`.`conversation-id`
2016 LEFT JOIN `item-uri` AS `external-item-uri` ON `external-item-uri`.`id` = `post-user`.`external-id`
2017 LEFT JOIN `verb` ON `verb`.`id` = `post-user`.`vid`
2018 LEFT JOIN `event` ON `event`.`id` = `post-user`.`event-id`
2019 LEFT JOIN `diaspora-interaction` ON `diaspora-interaction`.`uri-id` = `post-user`.`uri-id`
2020 LEFT JOIN `post-content` ON `post-content`.`uri-id` = `post-user`.`uri-id`
2021 LEFT JOIN `item-uri` AS `quote-item-uri` ON `quote-item-uri`.`id` = `post-content`.`quote-uri-id`
2022 LEFT JOIN `post-delivery-data` ON `post-delivery-data`.`uri-id` = `post-user`.`uri-id` AND `post-user`.`origin`
2023 LEFT JOIN `post-question` ON `post-question`.`uri-id` = `post-user`.`uri-id`
2024 LEFT JOIN `permissionset` ON `permissionset`.`id` = `post-user`.`psid`
2025 LEFT JOIN `post-user` AS `parent-post` ON `parent-post`.`uri-id` = `post-user`.`parent-uri-id` AND `parent-post`.`uid` = `post-user`.`uid`
2026 LEFT JOIN `contact` AS `parent-post-author` ON `parent-post-author`.`id` = `parent-post`.`author-id`;
2029 -- VIEW post-thread-user-view
2031 DROP VIEW IF EXISTS `post-thread-user-view`;
2032 CREATE VIEW `post-thread-user-view` AS SELECT
2033 `post-user`.`id` AS `id`,
2034 `post-user`.`id` AS `post-user-id`,
2035 `post-thread-user`.`uid` AS `uid`,
2036 `parent-post`.`id` AS `parent`,
2037 `item-uri`.`uri` AS `uri`,
2038 `post-thread-user`.`uri-id` AS `uri-id`,
2039 `parent-item-uri`.`uri` AS `parent-uri`,
2040 `post-user`.`parent-uri-id` AS `parent-uri-id`,
2041 `thr-parent-item-uri`.`uri` AS `thr-parent`,
2042 `post-user`.`thr-parent-id` AS `thr-parent-id`,
2043 `conversation-item-uri`.`uri` AS `conversation`,
2044 `post-thread-user`.`conversation-id` AS `conversation-id`,
2045 `quote-item-uri`.`uri` AS `quote-uri`,
2046 `post-content`.`quote-uri-id` AS `quote-uri-id`,
2047 `item-uri`.`guid` AS `guid`,
2048 `post-thread-user`.`wall` AS `wall`,
2049 `post-user`.`gravity` AS `gravity`,
2050 `external-item-uri`.`uri` AS `extid`,
2051 `post-user`.`external-id` AS `external-id`,
2052 `post-thread-user`.`created` AS `created`,
2053 `post-user`.`edited` AS `edited`,
2054 `post-thread-user`.`commented` AS `commented`,
2055 `post-thread-user`.`received` AS `received`,
2056 `post-thread-user`.`changed` AS `changed`,
2057 `post-user`.`post-type` AS `post-type`,
2058 `post-user`.`post-reason` AS `post-reason`,
2059 `post-user`.`private` AS `private`,
2060 `post-thread-user`.`pubmail` AS `pubmail`,
2061 `post-thread-user`.`ignored` AS `ignored`,
2062 `post-user`.`visible` AS `visible`,
2063 `post-thread-user`.`starred` AS `starred`,
2064 `post-thread-user`.`unseen` AS `unseen`,
2065 `post-user`.`deleted` AS `deleted`,
2066 `post-thread-user`.`origin` AS `origin`,
2067 `post-thread-user`.`mention` AS `mention`,
2068 `post-user`.`global` AS `global`,
2069 EXISTS(SELECT `type` FROM `post-collection` WHERE `type` = 0 AND `uri-id` = `post-thread-user`.`uri-id`) AS `featured`,
2070 `post-thread-user`.`network` AS `network`,
2071 `post-user`.`vid` AS `vid`,
2072 `post-thread-user`.`psid` AS `psid`,
2073 IF (`post-user`.`vid` IS NULL, '', `verb`.`name`) AS `verb`,
2074 `post-content`.`title` AS `title`,
2075 `post-content`.`content-warning` AS `content-warning`,
2076 `post-content`.`raw-body` AS `raw-body`,
2077 `post-content`.`body` AS `body`,
2078 `post-content`.`rendered-hash` AS `rendered-hash`,
2079 `post-content`.`rendered-html` AS `rendered-html`,
2080 `post-content`.`language` AS `language`,
2081 `post-content`.`plink` AS `plink`,
2082 `post-content`.`location` AS `location`,
2083 `post-content`.`coord` AS `coord`,
2084 `post-content`.`app` AS `app`,
2085 `post-content`.`object-type` AS `object-type`,
2086 `post-content`.`object` AS `object`,
2087 `post-content`.`target-type` AS `target-type`,
2088 `post-content`.`target` AS `target`,
2089 `post-content`.`resource-id` AS `resource-id`,
2090 `post-thread-user`.`contact-id` AS `contact-id`,
2091 `contact`.`uri-id` AS `contact-uri-id`,
2092 `contact`.`url` AS `contact-link`,
2093 `contact`.`addr` AS `contact-addr`,
2094 `contact`.`name` AS `contact-name`,
2095 `contact`.`nick` AS `contact-nick`,
2096 `contact`.`thumb` AS `contact-avatar`,
2097 `contact`.`network` AS `contact-network`,
2098 `contact`.`blocked` AS `contact-blocked`,
2099 `contact`.`hidden` AS `contact-hidden`,
2100 `contact`.`readonly` AS `contact-readonly`,
2101 `contact`.`archive` AS `contact-archive`,
2102 `contact`.`pending` AS `contact-pending`,
2103 `contact`.`rel` AS `contact-rel`,
2104 `contact`.`uid` AS `contact-uid`,
2105 `contact`.`contact-type` AS `contact-contact-type`,
2106 IF (`post-user`.`network` IN ('apub', 'dfrn', 'dspr', 'stat'), true, `contact`.`writable`) AS `writable`,
2107 `contact`.`self` AS `self`,
2108 `contact`.`id` AS `cid`,
2109 `contact`.`alias` AS `alias`,
2110 `contact`.`photo` AS `photo`,
2111 `contact`.`name-date` AS `name-date`,
2112 `contact`.`uri-date` AS `uri-date`,
2113 `contact`.`avatar-date` AS `avatar-date`,
2114 `contact`.`thumb` AS `thumb`,
2115 `post-thread-user`.`author-id` AS `author-id`,
2116 `author`.`uri-id` AS `author-uri-id`,
2117 `author`.`url` AS `author-link`,
2118 `author`.`addr` AS `author-addr`,
2119 IF (`contact`.`url` = `author`.`url` AND `contact`.`name` != '', `contact`.`name`, `author`.`name`) AS `author-name`,
2120 `author`.`nick` AS `author-nick`,
2121 IF (`contact`.`url` = `author`.`url` AND `contact`.`thumb` != '', `contact`.`thumb`, `author`.`thumb`) AS `author-avatar`,
2122 `author`.`network` AS `author-network`,
2123 `author`.`blocked` AS `author-blocked`,
2124 `author`.`hidden` AS `author-hidden`,
2125 `author`.`updated` AS `author-updated`,
2126 `author`.`gsid` AS `author-gsid`,
2127 `post-thread-user`.`owner-id` AS `owner-id`,
2128 `owner`.`uri-id` AS `owner-uri-id`,
2129 `owner`.`url` AS `owner-link`,
2130 `owner`.`addr` AS `owner-addr`,
2131 IF (`contact`.`url` = `owner`.`url` AND `contact`.`name` != '', `contact`.`name`, `owner`.`name`) AS `owner-name`,
2132 `owner`.`nick` AS `owner-nick`,
2133 IF (`contact`.`url` = `owner`.`url` AND `contact`.`thumb` != '', `contact`.`thumb`, `owner`.`thumb`) AS `owner-avatar`,
2134 `owner`.`network` AS `owner-network`,
2135 `owner`.`blocked` AS `owner-blocked`,
2136 `owner`.`hidden` AS `owner-hidden`,
2137 `owner`.`updated` AS `owner-updated`,
2138 `owner`.`contact-type` AS `owner-contact-type`,
2139 `post-thread-user`.`causer-id` AS `causer-id`,
2140 `causer`.`uri-id` AS `causer-uri-id`,
2141 `causer`.`url` AS `causer-link`,
2142 `causer`.`addr` AS `causer-addr`,
2143 `causer`.`name` AS `causer-name`,
2144 `causer`.`nick` AS `causer-nick`,
2145 `causer`.`thumb` AS `causer-avatar`,
2146 `causer`.`network` AS `causer-network`,
2147 `causer`.`blocked` AS `causer-blocked`,
2148 `causer`.`hidden` AS `causer-hidden`,
2149 `causer`.`contact-type` AS `causer-contact-type`,
2150 `post-delivery-data`.`postopts` AS `postopts`,
2151 `post-delivery-data`.`inform` AS `inform`,
2152 `post-delivery-data`.`queue_count` AS `delivery_queue_count`,
2153 `post-delivery-data`.`queue_done` AS `delivery_queue_done`,
2154 `post-delivery-data`.`queue_failed` AS `delivery_queue_failed`,
2155 IF (`post-thread-user`.`psid` IS NULL, '', `permissionset`.`allow_cid`) AS `allow_cid`,
2156 IF (`post-thread-user`.`psid` IS NULL, '', `permissionset`.`allow_gid`) AS `allow_gid`,
2157 IF (`post-thread-user`.`psid` IS NULL, '', `permissionset`.`deny_cid`) AS `deny_cid`,
2158 IF (`post-thread-user`.`psid` IS NULL, '', `permissionset`.`deny_gid`) AS `deny_gid`,
2159 `post-user`.`event-id` AS `event-id`,
2160 `event`.`created` AS `event-created`,
2161 `event`.`edited` AS `event-edited`,
2162 `event`.`start` AS `event-start`,
2163 `event`.`finish` AS `event-finish`,
2164 `event`.`summary` AS `event-summary`,
2165 `event`.`desc` AS `event-desc`,
2166 `event`.`location` AS `event-location`,
2167 `event`.`type` AS `event-type`,
2168 `event`.`nofinish` AS `event-nofinish`,
2169 `event`.`ignore` AS `event-ignore`,
2170 `post-question`.`id` AS `question-id`,
2171 `post-question`.`multiple` AS `question-multiple`,
2172 `post-question`.`voters` AS `question-voters`,
2173 `post-question`.`end-time` AS `question-end-time`,
2174 EXISTS(SELECT `uri-id` FROM `post-category` WHERE `post-category`.`uri-id` = `post-thread-user`.`uri-id` AND `post-category`.`uid` = `post-thread-user`.`uid`) AS `has-categories`,
2175 EXISTS(SELECT `id` FROM `post-media` WHERE `post-media`.`uri-id` = `post-thread-user`.`uri-id`) AS `has-media`,
2176 `diaspora-interaction`.`interaction` AS `signed_text`,
2177 `parent-item-uri`.`guid` AS `parent-guid`,
2178 `parent-post`.`network` AS `parent-network`,
2179 `parent-post`.`author-id` AS `parent-author-id`,
2180 `parent-post-author`.`url` AS `parent-author-link`,
2181 `parent-post-author`.`name` AS `parent-author-name`,
2182 `parent-post-author`.`network` AS `parent-author-network`
2183 FROM `post-thread-user`
2184 INNER JOIN `post-user` ON `post-user`.`id` = `post-thread-user`.`post-user-id`
2185 STRAIGHT_JOIN `contact` ON `contact`.`id` = `post-thread-user`.`contact-id`
2186 STRAIGHT_JOIN `contact` AS `author` ON `author`.`id` = `post-thread-user`.`author-id`
2187 STRAIGHT_JOIN `contact` AS `owner` ON `owner`.`id` = `post-thread-user`.`owner-id`
2188 LEFT JOIN `contact` AS `causer` ON `causer`.`id` = `post-thread-user`.`causer-id`
2189 LEFT JOIN `item-uri` ON `item-uri`.`id` = `post-thread-user`.`uri-id`
2190 LEFT JOIN `item-uri` AS `thr-parent-item-uri` ON `thr-parent-item-uri`.`id` = `post-user`.`thr-parent-id`
2191 LEFT JOIN `item-uri` AS `parent-item-uri` ON `parent-item-uri`.`id` = `post-user`.`parent-uri-id`
2192 LEFT JOIN `item-uri` AS `conversation-item-uri` ON `conversation-item-uri`.`id` = `post-thread-user`.`conversation-id`
2193 LEFT JOIN `item-uri` AS `external-item-uri` ON `external-item-uri`.`id` = `post-user`.`external-id`
2194 LEFT JOIN `verb` ON `verb`.`id` = `post-user`.`vid`
2195 LEFT JOIN `event` ON `event`.`id` = `post-user`.`event-id`
2196 LEFT JOIN `diaspora-interaction` ON `diaspora-interaction`.`uri-id` = `post-thread-user`.`uri-id`
2197 LEFT JOIN `post-content` ON `post-content`.`uri-id` = `post-thread-user`.`uri-id`
2198 LEFT JOIN `item-uri` AS `quote-item-uri` ON `quote-item-uri`.`id` = `post-content`.`quote-uri-id`
2199 LEFT JOIN `post-delivery-data` ON `post-delivery-data`.`uri-id` = `post-thread-user`.`uri-id` AND `post-thread-user`.`origin`
2200 LEFT JOIN `post-question` ON `post-question`.`uri-id` = `post-thread-user`.`uri-id`
2201 LEFT JOIN `permissionset` ON `permissionset`.`id` = `post-thread-user`.`psid`
2202 LEFT JOIN `post-user` AS `parent-post` ON `parent-post`.`uri-id` = `post-user`.`parent-uri-id` AND `parent-post`.`uid` = `post-thread-user`.`uid`
2203 LEFT JOIN `contact` AS `parent-post-author` ON `parent-post-author`.`id` = `parent-post`.`author-id`;
2208 DROP VIEW IF EXISTS `post-view`;
2209 CREATE VIEW `post-view` AS SELECT
2210 `item-uri`.`uri` AS `uri`,
2211 `post`.`uri-id` AS `uri-id`,
2212 `parent-item-uri`.`uri` AS `parent-uri`,
2213 `post`.`parent-uri-id` AS `parent-uri-id`,
2214 `thr-parent-item-uri`.`uri` AS `thr-parent`,
2215 `post`.`thr-parent-id` AS `thr-parent-id`,
2216 `conversation-item-uri`.`uri` AS `conversation`,
2217 `post-thread`.`conversation-id` AS `conversation-id`,
2218 `quote-item-uri`.`uri` AS `quote-uri`,
2219 `post-content`.`quote-uri-id` AS `quote-uri-id`,
2220 `item-uri`.`guid` AS `guid`,
2221 `post`.`gravity` AS `gravity`,
2222 `external-item-uri`.`uri` AS `extid`,
2223 `post`.`external-id` AS `external-id`,
2224 `post`.`created` AS `created`,
2225 `post`.`edited` AS `edited`,
2226 `post-thread`.`commented` AS `commented`,
2227 `post`.`received` AS `received`,
2228 `post-thread`.`changed` AS `changed`,
2229 `post`.`post-type` AS `post-type`,
2230 `post`.`private` AS `private`,
2231 `post`.`visible` AS `visible`,
2232 `post`.`deleted` AS `deleted`,
2233 `post`.`global` AS `global`,
2234 EXISTS(SELECT `type` FROM `post-collection` WHERE `type` = 0 AND `uri-id` = `post`.`uri-id`) AS `featured`,
2235 `post`.`network` AS `network`,
2236 `post`.`vid` AS `vid`,
2237 IF (`post`.`vid` IS NULL, '', `verb`.`name`) AS `verb`,
2238 `post-content`.`title` AS `title`,
2239 `post-content`.`content-warning` AS `content-warning`,
2240 `post-content`.`raw-body` AS `raw-body`,
2241 `post-content`.`body` AS `body`,
2242 `post-content`.`rendered-hash` AS `rendered-hash`,
2243 `post-content`.`rendered-html` AS `rendered-html`,
2244 `post-content`.`language` AS `language`,
2245 `post-content`.`plink` AS `plink`,
2246 `post-content`.`location` AS `location`,
2247 `post-content`.`coord` AS `coord`,
2248 `post-content`.`app` AS `app`,
2249 `post-content`.`object-type` AS `object-type`,
2250 `post-content`.`object` AS `object`,
2251 `post-content`.`target-type` AS `target-type`,
2252 `post-content`.`target` AS `target`,
2253 `post-content`.`resource-id` AS `resource-id`,
2254 `post`.`author-id` AS `contact-id`,
2255 `author`.`uri-id` AS `contact-uri-id`,
2256 `author`.`url` AS `contact-link`,
2257 `author`.`addr` AS `contact-addr`,
2258 `author`.`name` AS `contact-name`,
2259 `author`.`nick` AS `contact-nick`,
2260 `author`.`thumb` AS `contact-avatar`,
2261 `author`.`network` AS `contact-network`,
2262 `author`.`blocked` AS `contact-blocked`,
2263 `author`.`hidden` AS `contact-hidden`,
2264 `author`.`readonly` AS `contact-readonly`,
2265 `author`.`archive` AS `contact-archive`,
2266 `author`.`pending` AS `contact-pending`,
2267 `author`.`rel` AS `contact-rel`,
2268 `author`.`uid` AS `contact-uid`,
2269 `author`.`contact-type` AS `contact-contact-type`,
2270 IF (`post`.`network` IN ('apub', 'dfrn', 'dspr', 'stat'), true, `author`.`writable`) AS `writable`,
2272 `author`.`id` AS `cid`,
2273 `author`.`alias` AS `alias`,
2274 `author`.`photo` AS `photo`,
2275 `author`.`name-date` AS `name-date`,
2276 `author`.`uri-date` AS `uri-date`,
2277 `author`.`avatar-date` AS `avatar-date`,
2278 `author`.`thumb` AS `thumb`,
2279 `post`.`author-id` AS `author-id`,
2280 `author`.`uri-id` AS `author-uri-id`,
2281 `author`.`url` AS `author-link`,
2282 `author`.`addr` AS `author-addr`,
2283 `author`.`name` AS `author-name`,
2284 `author`.`nick` AS `author-nick`,
2285 `author`.`thumb` AS `author-avatar`,
2286 `author`.`network` AS `author-network`,
2287 `author`.`blocked` AS `author-blocked`,
2288 `author`.`hidden` AS `author-hidden`,
2289 `author`.`updated` AS `author-updated`,
2290 `author`.`gsid` AS `author-gsid`,
2291 `post`.`owner-id` AS `owner-id`,
2292 `owner`.`uri-id` AS `owner-uri-id`,
2293 `owner`.`url` AS `owner-link`,
2294 `owner`.`addr` AS `owner-addr`,
2295 `owner`.`name` AS `owner-name`,
2296 `owner`.`nick` AS `owner-nick`,
2297 `owner`.`thumb` AS `owner-avatar`,
2298 `owner`.`network` AS `owner-network`,
2299 `owner`.`blocked` AS `owner-blocked`,
2300 `owner`.`hidden` AS `owner-hidden`,
2301 `owner`.`updated` AS `owner-updated`,
2302 `owner`.`contact-type` AS `owner-contact-type`,
2303 `post`.`causer-id` AS `causer-id`,
2304 `causer`.`uri-id` AS `causer-uri-id`,
2305 `causer`.`url` AS `causer-link`,
2306 `causer`.`addr` AS `causer-addr`,
2307 `causer`.`name` AS `causer-name`,
2308 `causer`.`nick` AS `causer-nick`,
2309 `causer`.`thumb` AS `causer-avatar`,
2310 `causer`.`network` AS `causer-network`,
2311 `causer`.`blocked` AS `causer-blocked`,
2312 `causer`.`hidden` AS `causer-hidden`,
2313 `causer`.`contact-type` AS `causer-contact-type`,
2314 `post-question`.`id` AS `question-id`,
2315 `post-question`.`multiple` AS `question-multiple`,
2316 `post-question`.`voters` AS `question-voters`,
2317 `post-question`.`end-time` AS `question-end-time`,
2318 0 AS `has-categories`,
2319 EXISTS(SELECT `id` FROM `post-media` WHERE `post-media`.`uri-id` = `post`.`uri-id`) AS `has-media`,
2320 `diaspora-interaction`.`interaction` AS `signed_text`,
2321 `parent-item-uri`.`guid` AS `parent-guid`,
2322 `parent-post`.`network` AS `parent-network`,
2323 `parent-post`.`author-id` AS `parent-author-id`,
2324 `parent-post-author`.`url` AS `parent-author-link`,
2325 `parent-post-author`.`name` AS `parent-author-name`,
2326 `parent-post-author`.`network` AS `parent-author-network`
2328 STRAIGHT_JOIN `post-thread` ON `post-thread`.`uri-id` = `post`.`parent-uri-id`
2329 STRAIGHT_JOIN `contact` AS `author` ON `author`.`id` = `post`.`author-id`
2330 STRAIGHT_JOIN `contact` AS `owner` ON `owner`.`id` = `post`.`owner-id`
2331 LEFT JOIN `contact` AS `causer` ON `causer`.`id` = `post`.`causer-id`
2332 LEFT JOIN `item-uri` ON `item-uri`.`id` = `post`.`uri-id`
2333 LEFT JOIN `item-uri` AS `thr-parent-item-uri` ON `thr-parent-item-uri`.`id` = `post`.`thr-parent-id`
2334 LEFT JOIN `item-uri` AS `parent-item-uri` ON `parent-item-uri`.`id` = `post`.`parent-uri-id`
2335 LEFT JOIN `item-uri` AS `conversation-item-uri` ON `conversation-item-uri`.`id` = `post-thread`.`conversation-id`
2336 LEFT JOIN `item-uri` AS `external-item-uri` ON `external-item-uri`.`id` = `post`.`external-id`
2337 LEFT JOIN `verb` ON `verb`.`id` = `post`.`vid`
2338 LEFT JOIN `diaspora-interaction` ON `diaspora-interaction`.`uri-id` = `post`.`uri-id`
2339 LEFT JOIN `post-content` ON `post-content`.`uri-id` = `post`.`uri-id`
2340 LEFT JOIN `item-uri` AS `quote-item-uri` ON `quote-item-uri`.`id` = `post-content`.`quote-uri-id`
2341 LEFT JOIN `post-question` ON `post-question`.`uri-id` = `post`.`uri-id`
2342 LEFT JOIN `post` AS `parent-post` ON `parent-post`.`uri-id` = `post`.`parent-uri-id`
2343 LEFT JOIN `contact` AS `parent-post-author` ON `parent-post-author`.`id` = `parent-post`.`author-id`;
2346 -- VIEW post-thread-view
2348 DROP VIEW IF EXISTS `post-thread-view`;
2349 CREATE VIEW `post-thread-view` AS SELECT
2350 `item-uri`.`uri` AS `uri`,
2351 `post-thread`.`uri-id` AS `uri-id`,
2352 `parent-item-uri`.`uri` AS `parent-uri`,
2353 `post`.`parent-uri-id` AS `parent-uri-id`,
2354 `thr-parent-item-uri`.`uri` AS `thr-parent`,
2355 `post`.`thr-parent-id` AS `thr-parent-id`,
2356 `conversation-item-uri`.`uri` AS `conversation`,
2357 `post-thread`.`conversation-id` AS `conversation-id`,
2358 `quote-item-uri`.`uri` AS `quote-uri`,
2359 `post-content`.`quote-uri-id` AS `quote-uri-id`,
2360 `item-uri`.`guid` AS `guid`,
2361 `post`.`gravity` AS `gravity`,
2362 `external-item-uri`.`uri` AS `extid`,
2363 `post`.`external-id` AS `external-id`,
2364 `post-thread`.`created` AS `created`,
2365 `post`.`edited` AS `edited`,
2366 `post-thread`.`commented` AS `commented`,
2367 `post-thread`.`received` AS `received`,
2368 `post-thread`.`changed` AS `changed`,
2369 `post`.`post-type` AS `post-type`,
2370 `post`.`private` AS `private`,
2371 `post`.`visible` AS `visible`,
2372 `post`.`deleted` AS `deleted`,
2373 `post`.`global` AS `global`,
2374 EXISTS(SELECT `type` FROM `post-collection` WHERE `type` = 0 AND `uri-id` = `post-thread`.`uri-id`) AS `featured`,
2375 `post-thread`.`network` AS `network`,
2376 `post`.`vid` AS `vid`,
2377 IF (`post`.`vid` IS NULL, '', `verb`.`name`) AS `verb`,
2378 `post-content`.`title` AS `title`,
2379 `post-content`.`content-warning` AS `content-warning`,
2380 `post-content`.`raw-body` AS `raw-body`,
2381 `post-content`.`body` AS `body`,
2382 `post-content`.`rendered-hash` AS `rendered-hash`,
2383 `post-content`.`rendered-html` AS `rendered-html`,
2384 `post-content`.`language` AS `language`,
2385 `post-content`.`plink` AS `plink`,
2386 `post-content`.`location` AS `location`,
2387 `post-content`.`coord` AS `coord`,
2388 `post-content`.`app` AS `app`,
2389 `post-content`.`object-type` AS `object-type`,
2390 `post-content`.`object` AS `object`,
2391 `post-content`.`target-type` AS `target-type`,
2392 `post-content`.`target` AS `target`,
2393 `post-content`.`resource-id` AS `resource-id`,
2394 `post-thread`.`author-id` AS `contact-id`,
2395 `author`.`uri-id` AS `contact-uri-id`,
2396 `author`.`url` AS `contact-link`,
2397 `author`.`addr` AS `contact-addr`,
2398 `author`.`name` AS `contact-name`,
2399 `author`.`nick` AS `contact-nick`,
2400 `author`.`thumb` AS `contact-avatar`,
2401 `author`.`network` AS `contact-network`,
2402 `author`.`blocked` AS `contact-blocked`,
2403 `author`.`hidden` AS `contact-hidden`,
2404 `author`.`readonly` AS `contact-readonly`,
2405 `author`.`archive` AS `contact-archive`,
2406 `author`.`pending` AS `contact-pending`,
2407 `author`.`rel` AS `contact-rel`,
2408 `author`.`uid` AS `contact-uid`,
2409 `author`.`contact-type` AS `contact-contact-type`,
2410 IF (`post`.`network` IN ('apub', 'dfrn', 'dspr', 'stat'), true, `author`.`writable`) AS `writable`,
2412 `author`.`id` AS `cid`,
2413 `author`.`alias` AS `alias`,
2414 `author`.`photo` AS `photo`,
2415 `author`.`name-date` AS `name-date`,
2416 `author`.`uri-date` AS `uri-date`,
2417 `author`.`avatar-date` AS `avatar-date`,
2418 `author`.`thumb` AS `thumb`,
2419 `post-thread`.`author-id` AS `author-id`,
2420 `author`.`uri-id` AS `author-uri-id`,
2421 `author`.`url` AS `author-link`,
2422 `author`.`addr` AS `author-addr`,
2423 `author`.`name` AS `author-name`,
2424 `author`.`nick` AS `author-nick`,
2425 `author`.`thumb` AS `author-avatar`,
2426 `author`.`network` AS `author-network`,
2427 `author`.`blocked` AS `author-blocked`,
2428 `author`.`hidden` AS `author-hidden`,
2429 `author`.`updated` AS `author-updated`,
2430 `author`.`gsid` AS `author-gsid`,
2431 `post-thread`.`owner-id` AS `owner-id`,
2432 `owner`.`uri-id` AS `owner-uri-id`,
2433 `owner`.`url` AS `owner-link`,
2434 `owner`.`addr` AS `owner-addr`,
2435 `owner`.`name` AS `owner-name`,
2436 `owner`.`nick` AS `owner-nick`,
2437 `owner`.`thumb` AS `owner-avatar`,
2438 `owner`.`network` AS `owner-network`,
2439 `owner`.`blocked` AS `owner-blocked`,
2440 `owner`.`hidden` AS `owner-hidden`,
2441 `owner`.`updated` AS `owner-updated`,
2442 `owner`.`contact-type` AS `owner-contact-type`,
2443 `post-thread`.`causer-id` AS `causer-id`,
2444 `causer`.`uri-id` AS `causer-uri-id`,
2445 `causer`.`url` AS `causer-link`,
2446 `causer`.`addr` AS `causer-addr`,
2447 `causer`.`name` AS `causer-name`,
2448 `causer`.`nick` AS `causer-nick`,
2449 `causer`.`thumb` AS `causer-avatar`,
2450 `causer`.`network` AS `causer-network`,
2451 `causer`.`blocked` AS `causer-blocked`,
2452 `causer`.`hidden` AS `causer-hidden`,
2453 `causer`.`contact-type` AS `causer-contact-type`,
2454 `post-question`.`id` AS `question-id`,
2455 `post-question`.`multiple` AS `question-multiple`,
2456 `post-question`.`voters` AS `question-voters`,
2457 `post-question`.`end-time` AS `question-end-time`,
2458 0 AS `has-categories`,
2459 EXISTS(SELECT `id` FROM `post-media` WHERE `post-media`.`uri-id` = `post-thread`.`uri-id`) AS `has-media`,
2460 (SELECT COUNT(*) FROM `post` WHERE `parent-uri-id` = `post-thread`.`uri-id` AND `gravity` = 6) AS `total-comments`,
2461 (SELECT COUNT(DISTINCT(`author-id`)) FROM `post` WHERE `parent-uri-id` = `post-thread`.`uri-id` AND `gravity` = 6) AS `total-actors`,
2462 `diaspora-interaction`.`interaction` AS `signed_text`,
2463 `parent-item-uri`.`guid` AS `parent-guid`,
2464 `parent-post`.`network` AS `parent-network`,
2465 `parent-post`.`author-id` AS `parent-author-id`,
2466 `parent-post-author`.`url` AS `parent-author-link`,
2467 `parent-post-author`.`name` AS `parent-author-name`,
2468 `parent-post-author`.`network` AS `parent-author-network`
2470 INNER JOIN `post` ON `post`.`uri-id` = `post-thread`.`uri-id`
2471 STRAIGHT_JOIN `contact` AS `author` ON `author`.`id` = `post-thread`.`author-id`
2472 STRAIGHT_JOIN `contact` AS `owner` ON `owner`.`id` = `post-thread`.`owner-id`
2473 LEFT JOIN `contact` AS `causer` ON `causer`.`id` = `post-thread`.`causer-id`
2474 LEFT JOIN `item-uri` ON `item-uri`.`id` = `post-thread`.`uri-id`
2475 LEFT JOIN `item-uri` AS `thr-parent-item-uri` ON `thr-parent-item-uri`.`id` = `post`.`thr-parent-id`
2476 LEFT JOIN `item-uri` AS `parent-item-uri` ON `parent-item-uri`.`id` = `post`.`parent-uri-id`
2477 LEFT JOIN `item-uri` AS `conversation-item-uri` ON `conversation-item-uri`.`id` = `post-thread`.`conversation-id`
2478 LEFT JOIN `item-uri` AS `external-item-uri` ON `external-item-uri`.`id` = `post`.`external-id`
2479 LEFT JOIN `verb` ON `verb`.`id` = `post`.`vid`
2480 LEFT JOIN `diaspora-interaction` ON `diaspora-interaction`.`uri-id` = `post-thread`.`uri-id`
2481 LEFT JOIN `post-content` ON `post-content`.`uri-id` = `post-thread`.`uri-id`
2482 LEFT JOIN `item-uri` AS `quote-item-uri` ON `quote-item-uri`.`id` = `post-content`.`quote-uri-id`
2483 LEFT JOIN `post-question` ON `post-question`.`uri-id` = `post-thread`.`uri-id`
2484 LEFT JOIN `post` AS `parent-post` ON `parent-post`.`uri-id` = `post`.`parent-uri-id`
2485 LEFT JOIN `contact` AS `parent-post-author` ON `parent-post-author`.`id` = `parent-post`.`author-id`;
2488 -- VIEW category-view
2490 DROP VIEW IF EXISTS `category-view`;
2491 CREATE VIEW `category-view` AS SELECT
2492 `post-category`.`uri-id` AS `uri-id`,
2493 `post-category`.`uid` AS `uid`,
2494 `post-category`.`type` AS `type`,
2495 `post-category`.`tid` AS `tid`,
2496 `tag`.`name` AS `name`,
2497 `tag`.`url` AS `url`
2498 FROM `post-category`
2499 LEFT JOIN `tag` ON `post-category`.`tid` = `tag`.`id`;
2502 -- VIEW collection-view
2504 DROP VIEW IF EXISTS `collection-view`;
2505 CREATE VIEW `collection-view` AS SELECT
2506 `post-collection`.`uri-id` AS `uri-id`,
2507 `post-collection`.`type` AS `type`,
2508 `post-collection`.`author-id` AS `cid`,
2509 `post`.`received` AS `received`,
2510 `post`.`created` AS `created`,
2511 `post-thread`.`commented` AS `commented`,
2512 `post`.`private` AS `private`,
2513 `post`.`visible` AS `visible`,
2514 `post`.`deleted` AS `deleted`,
2515 `post`.`thr-parent-id` AS `thr-parent-id`,
2516 `post-collection`.`author-id` AS `author-id`,
2517 `post`.`gravity` AS `gravity`
2518 FROM `post-collection`
2519 INNER JOIN `post` ON `post-collection`.`uri-id` = `post`.`uri-id`
2520 INNER JOIN `post-thread` ON `post-thread`.`uri-id` = `post`.`parent-uri-id`;
2525 DROP VIEW IF EXISTS `media-view`;
2526 CREATE VIEW `media-view` AS SELECT
2527 `post-media`.`uri-id` AS `uri-id`,
2528 `post-media`.`type` AS `type`,
2529 `post`.`received` AS `received`,
2530 `post`.`created` AS `created`,
2531 `post`.`private` AS `private`,
2532 `post`.`visible` AS `visible`,
2533 `post`.`deleted` AS `deleted`,
2534 `post`.`thr-parent-id` AS `thr-parent-id`,
2535 `post`.`author-id` AS `author-id`,
2536 `post`.`gravity` AS `gravity`
2538 INNER JOIN `post` ON `post-media`.`uri-id` = `post`.`uri-id`;
2543 DROP VIEW IF EXISTS `tag-view`;
2544 CREATE VIEW `tag-view` AS SELECT
2545 `post-tag`.`uri-id` AS `uri-id`,
2546 `post-tag`.`type` AS `type`,
2547 `post-tag`.`tid` AS `tid`,
2548 `post-tag`.`cid` AS `cid`,
2549 CASE `cid` WHEN 0 THEN `tag`.`name` ELSE `contact`.`name` END AS `name`,
2550 CASE `cid` WHEN 0 THEN `tag`.`url` ELSE `contact`.`url` END AS `url`,
2551 CASE `cid` WHEN 0 THEN `tag`.`type` ELSE 1 END AS `tag-type`
2553 LEFT JOIN `tag` ON `post-tag`.`tid` = `tag`.`id`
2554 LEFT JOIN `contact` ON `post-tag`.`cid` = `contact`.`id`;
2557 -- VIEW network-item-view
2559 DROP VIEW IF EXISTS `network-item-view`;
2560 CREATE VIEW `network-item-view` AS SELECT
2561 `post-user`.`uri-id` AS `uri-id`,
2562 `parent-post`.`id` AS `parent`,
2563 `post-user`.`received` AS `received`,
2564 `post-thread-user`.`commented` AS `commented`,
2565 `post-user`.`created` AS `created`,
2566 `post-user`.`uid` AS `uid`,
2567 `post-thread-user`.`starred` AS `starred`,
2568 `post-thread-user`.`mention` AS `mention`,
2569 `post-user`.`network` AS `network`,
2570 `post-user`.`unseen` AS `unseen`,
2571 `post-user`.`gravity` AS `gravity`,
2572 `post-user`.`contact-id` AS `contact-id`,
2573 `ownercontact`.`contact-type` AS `contact-type`
2575 STRAIGHT_JOIN `post-thread-user` ON `post-thread-user`.`uri-id` = `post-user`.`parent-uri-id` AND `post-thread-user`.`uid` = `post-user`.`uid`
2576 INNER JOIN `contact` ON `contact`.`id` = `post-thread-user`.`contact-id`
2577 LEFT JOIN `user-contact` AS `author` ON `author`.`uid` = `post-thread-user`.`uid` AND `author`.`cid` = `post-thread-user`.`author-id`
2578 LEFT JOIN `user-contact` AS `owner` ON `owner`.`uid` = `post-thread-user`.`uid` AND `owner`.`cid` = `post-thread-user`.`owner-id`
2579 INNER JOIN `contact` AS `ownercontact` ON `ownercontact`.`id` = `post-thread-user`.`owner-id`
2580 LEFT JOIN `post-user` AS `parent-post` ON `parent-post`.`uri-id` = `post-user`.`parent-uri-id` AND `parent-post`.`uid` = `post-user`.`uid`
2581 WHERE `post-user`.`visible` AND NOT `post-user`.`deleted`
2582 AND (NOT `contact`.`readonly` AND NOT `contact`.`blocked` AND NOT `contact`.`pending`)
2583 AND (`post-user`.`hidden` IS NULL OR NOT `post-user`.`hidden`)
2584 AND (`author`.`blocked` IS NULL OR NOT `author`.`blocked`)
2585 AND (`owner`.`blocked` IS NULL OR NOT `owner`.`blocked`);
2588 -- VIEW network-thread-view
2590 DROP VIEW IF EXISTS `network-thread-view`;
2591 CREATE VIEW `network-thread-view` AS SELECT
2592 `post-thread-user`.`uri-id` AS `uri-id`,
2593 `parent-post`.`id` AS `parent`,
2594 `post-thread-user`.`received` AS `received`,
2595 `post-thread-user`.`commented` AS `commented`,
2596 `post-thread-user`.`created` AS `created`,
2597 `post-thread-user`.`uid` AS `uid`,
2598 `post-thread-user`.`starred` AS `starred`,
2599 `post-thread-user`.`mention` AS `mention`,
2600 `post-thread-user`.`network` AS `network`,
2601 `post-thread-user`.`contact-id` AS `contact-id`,
2602 `ownercontact`.`contact-type` AS `contact-type`
2603 FROM `post-thread-user`
2604 INNER JOIN `post-user` ON `post-user`.`id` = `post-thread-user`.`post-user-id`
2605 STRAIGHT_JOIN `contact` ON `contact`.`id` = `post-thread-user`.`contact-id`
2606 LEFT JOIN `user-contact` AS `author` ON `author`.`uid` = `post-thread-user`.`uid` AND `author`.`cid` = `post-thread-user`.`author-id`
2607 LEFT JOIN `user-contact` AS `owner` ON `owner`.`uid` = `post-thread-user`.`uid` AND `owner`.`cid` = `post-thread-user`.`owner-id`
2608 LEFT JOIN `contact` AS `ownercontact` ON `ownercontact`.`id` = `post-thread-user`.`owner-id`
2609 LEFT JOIN `post-user` AS `parent-post` ON `parent-post`.`uri-id` = `post-user`.`parent-uri-id` AND `parent-post`.`uid` = `post-user`.`uid`
2610 WHERE `post-user`.`visible` AND NOT `post-user`.`deleted`
2611 AND (NOT `contact`.`readonly` AND NOT `contact`.`blocked` AND NOT `contact`.`pending`)
2612 AND (`post-thread-user`.`hidden` IS NULL OR NOT `post-thread-user`.`hidden`)
2613 AND (`author`.`blocked` IS NULL OR NOT `author`.`blocked`)
2614 AND (`owner`.`blocked` IS NULL OR NOT `owner`.`blocked`);
2619 DROP VIEW IF EXISTS `owner-view`;
2620 CREATE VIEW `owner-view` AS SELECT
2621 `contact`.`id` AS `id`,
2622 `contact`.`uid` AS `uid`,
2623 `contact`.`created` AS `created`,
2624 `contact`.`updated` AS `updated`,
2625 `contact`.`self` AS `self`,
2626 `contact`.`remote_self` AS `remote_self`,
2627 `contact`.`rel` AS `rel`,
2628 `contact`.`network` AS `network`,
2629 `contact`.`protocol` AS `protocol`,
2630 `contact`.`name` AS `name`,
2631 `contact`.`nick` AS `nick`,
2632 `contact`.`location` AS `location`,
2633 `contact`.`about` AS `about`,
2634 `contact`.`keywords` AS `keywords`,
2635 `contact`.`xmpp` AS `xmpp`,
2636 `contact`.`matrix` AS `matrix`,
2637 `contact`.`attag` AS `attag`,
2638 `contact`.`avatar` AS `avatar`,
2639 `contact`.`photo` AS `photo`,
2640 `contact`.`thumb` AS `thumb`,
2641 `contact`.`micro` AS `micro`,
2642 `contact`.`header` AS `header`,
2643 `contact`.`url` AS `url`,
2644 `contact`.`nurl` AS `nurl`,
2645 `contact`.`uri-id` AS `uri-id`,
2646 `contact`.`addr` AS `addr`,
2647 `contact`.`alias` AS `alias`,
2648 `contact`.`pubkey` AS `pubkey`,
2649 `contact`.`prvkey` AS `prvkey`,
2650 `contact`.`batch` AS `batch`,
2651 `contact`.`request` AS `request`,
2652 `contact`.`notify` AS `notify`,
2653 `contact`.`poll` AS `poll`,
2654 `contact`.`confirm` AS `confirm`,
2655 `contact`.`poco` AS `poco`,
2656 `contact`.`subhub` AS `subhub`,
2657 `contact`.`hub-verify` AS `hub-verify`,
2658 `contact`.`last-update` AS `last-update`,
2659 `contact`.`success_update` AS `success_update`,
2660 `contact`.`failure_update` AS `failure_update`,
2661 `contact`.`name-date` AS `name-date`,
2662 `contact`.`uri-date` AS `uri-date`,
2663 `contact`.`avatar-date` AS `avatar-date`,
2664 `contact`.`avatar-date` AS `picdate`,
2665 `contact`.`term-date` AS `term-date`,
2666 `contact`.`last-item` AS `last-item`,
2667 `contact`.`priority` AS `priority`,
2668 `user`.`blocked` AS `blocked`,
2669 `contact`.`block_reason` AS `block_reason`,
2670 `contact`.`readonly` AS `readonly`,
2671 `contact`.`writable` AS `writable`,
2672 `contact`.`forum` AS `forum`,
2673 `contact`.`prv` AS `prv`,
2674 `contact`.`contact-type` AS `contact-type`,
2675 `contact`.`manually-approve` AS `manually-approve`,
2676 `contact`.`hidden` AS `hidden`,
2677 `contact`.`archive` AS `archive`,
2678 `contact`.`pending` AS `pending`,
2679 `contact`.`deleted` AS `deleted`,
2680 `contact`.`unsearchable` AS `unsearchable`,
2681 `contact`.`sensitive` AS `sensitive`,
2682 `contact`.`baseurl` AS `baseurl`,
2683 `contact`.`reason` AS `reason`,
2684 `contact`.`info` AS `info`,
2685 `contact`.`bdyear` AS `bdyear`,
2686 `contact`.`bd` AS `bd`,
2687 `contact`.`notify_new_posts` AS `notify_new_posts`,
2688 `contact`.`fetch_further_information` AS `fetch_further_information`,
2689 `contact`.`ffi_keyword_denylist` AS `ffi_keyword_denylist`,
2690 `user`.`parent-uid` AS `parent-uid`,
2691 `user`.`guid` AS `guid`,
2692 `user`.`nickname` AS `nickname`,
2693 `user`.`email` AS `email`,
2694 `user`.`openid` AS `openid`,
2695 `user`.`timezone` AS `timezone`,
2696 `user`.`language` AS `language`,
2697 `user`.`register_date` AS `register_date`,
2698 `user`.`login_date` AS `login_date`,
2699 `user`.`last-activity` AS `last-activity`,
2700 `user`.`default-location` AS `default-location`,
2701 `user`.`allow_location` AS `allow_location`,
2702 `user`.`theme` AS `theme`,
2703 `user`.`pubkey` AS `upubkey`,
2704 `user`.`prvkey` AS `uprvkey`,
2705 `user`.`sprvkey` AS `sprvkey`,
2706 `user`.`spubkey` AS `spubkey`,
2707 `user`.`verified` AS `verified`,
2708 `user`.`blockwall` AS `blockwall`,
2709 `user`.`hidewall` AS `hidewall`,
2710 `user`.`blocktags` AS `blocktags`,
2711 `user`.`unkmail` AS `unkmail`,
2712 `user`.`cntunkmail` AS `cntunkmail`,
2713 `user`.`notify-flags` AS `notify-flags`,
2714 `user`.`page-flags` AS `page-flags`,
2715 `user`.`account-type` AS `account-type`,
2716 `user`.`prvnets` AS `prvnets`,
2717 `user`.`maxreq` AS `maxreq`,
2718 `user`.`expire` AS `expire`,
2719 `user`.`account_removed` AS `account_removed`,
2720 `user`.`account_expired` AS `account_expired`,
2721 `user`.`account_expires_on` AS `account_expires_on`,
2722 `user`.`expire_notification_sent` AS `expire_notification_sent`,
2723 `user`.`def_gid` AS `def_gid`,
2724 `user`.`allow_cid` AS `allow_cid`,
2725 `user`.`allow_gid` AS `allow_gid`,
2726 `user`.`deny_cid` AS `deny_cid`,
2727 `user`.`deny_gid` AS `deny_gid`,
2728 `user`.`openidserver` AS `openidserver`,
2729 `profile`.`publish` AS `publish`,
2730 `profile`.`net-publish` AS `net-publish`,
2731 `profile`.`hide-friends` AS `hide-friends`,
2732 `profile`.`prv_keywords` AS `prv_keywords`,
2733 `profile`.`pub_keywords` AS `pub_keywords`,
2734 `profile`.`address` AS `address`,
2735 `profile`.`locality` AS `locality`,
2736 `profile`.`region` AS `region`,
2737 `profile`.`postal-code` AS `postal-code`,
2738 `profile`.`country-name` AS `country-name`,
2739 `profile`.`homepage` AS `homepage`,
2740 `profile`.`homepage_verified` AS `homepage_verified`,
2741 `profile`.`dob` AS `dob`
2743 INNER JOIN `contact` ON `contact`.`uid` = `user`.`uid` AND `contact`.`self`
2744 INNER JOIN `profile` ON `profile`.`uid` = `user`.`uid`;
2747 -- VIEW account-view
2749 DROP VIEW IF EXISTS `account-view`;
2750 CREATE VIEW `account-view` AS SELECT
2751 `contact`.`id` AS `id`,
2752 `contact`.`url` AS `url`,
2753 `contact`.`nurl` AS `nurl`,
2754 `contact`.`uri-id` AS `uri-id`,
2755 `item-uri`.`guid` AS `guid`,
2756 `contact`.`addr` AS `addr`,
2757 `contact`.`alias` AS `alias`,
2758 `contact`.`name` AS `name`,
2759 `contact`.`nick` AS `nick`,
2760 `contact`.`about` AS `about`,
2761 `contact`.`keywords` AS `keywords`,
2762 `contact`.`xmpp` AS `xmpp`,
2763 `contact`.`matrix` AS `matrix`,
2764 `contact`.`avatar` AS `avatar`,
2765 `contact`.`photo` AS `photo`,
2766 `contact`.`thumb` AS `thumb`,
2767 `contact`.`micro` AS `micro`,
2768 `contact`.`header` AS `header`,
2769 `contact`.`created` AS `created`,
2770 `contact`.`updated` AS `updated`,
2771 `contact`.`network` AS `network`,
2772 `contact`.`protocol` AS `protocol`,
2773 `contact`.`location` AS `location`,
2774 `contact`.`attag` AS `attag`,
2775 `contact`.`pubkey` AS `pubkey`,
2776 `contact`.`prvkey` AS `prvkey`,
2777 `contact`.`subscribe` AS `subscribe`,
2778 `contact`.`last-update` AS `last-update`,
2779 `contact`.`success_update` AS `success_update`,
2780 `contact`.`failure_update` AS `failure_update`,
2781 `contact`.`failed` AS `failed`,
2782 `contact`.`last-item` AS `last-item`,
2783 `contact`.`last-discovery` AS `last-discovery`,
2784 `contact`.`contact-type` AS `contact-type`,
2785 `contact`.`manually-approve` AS `manually-approve`,
2786 `contact`.`unsearchable` AS `unsearchable`,
2787 `contact`.`sensitive` AS `sensitive`,
2788 `contact`.`baseurl` AS `baseurl`,
2789 `contact`.`gsid` AS `gsid`,
2790 `contact`.`info` AS `info`,
2791 `contact`.`bdyear` AS `bdyear`,
2792 `contact`.`bd` AS `bd`,
2793 `contact`.`poco` AS `poco`,
2794 `contact`.`name-date` AS `name-date`,
2795 `contact`.`uri-date` AS `uri-date`,
2796 `contact`.`avatar-date` AS `avatar-date`,
2797 `contact`.`term-date` AS `term-date`,
2798 `contact`.`hidden` AS `global-ignored`,
2799 `contact`.`blocked` AS `global-blocked`,
2800 `contact`.`hidden` AS `hidden`,
2801 `contact`.`archive` AS `archive`,
2802 `contact`.`deleted` AS `deleted`,
2803 `contact`.`blocked` AS `blocked`,
2804 `contact`.`notify` AS `dfrn-notify`,
2805 `contact`.`poll` AS `dfrn-poll`,
2806 `item-uri`.`guid` AS `diaspora-guid`,
2807 `diaspora-contact`.`batch` AS `diaspora-batch`,
2808 `diaspora-contact`.`notify` AS `diaspora-notify`,
2809 `diaspora-contact`.`poll` AS `diaspora-poll`,
2810 `diaspora-contact`.`alias` AS `diaspora-alias`,
2811 `apcontact`.`uuid` AS `ap-uuid`,
2812 `apcontact`.`type` AS `ap-type`,
2813 `apcontact`.`following` AS `ap-following`,
2814 `apcontact`.`followers` AS `ap-followers`,
2815 `apcontact`.`inbox` AS `ap-inbox`,
2816 `apcontact`.`outbox` AS `ap-outbox`,
2817 `apcontact`.`sharedinbox` AS `ap-sharedinbox`,
2818 `apcontact`.`generator` AS `ap-generator`,
2819 `apcontact`.`following_count` AS `ap-following_count`,
2820 `apcontact`.`followers_count` AS `ap-followers_count`,
2821 `apcontact`.`statuses_count` AS `ap-statuses_count`,
2822 `gserver`.`site_name` AS `site_name`,
2823 `gserver`.`platform` AS `platform`,
2824 `gserver`.`version` AS `version`
2826 LEFT JOIN `item-uri` ON `item-uri`.`id` = `contact`.`uri-id`
2827 LEFT JOIN `apcontact` ON `apcontact`.`uri-id` = `contact`.`uri-id`
2828 LEFT JOIN `diaspora-contact` ON `diaspora-contact`.`uri-id` = contact.`uri-id`
2829 LEFT JOIN `gserver` ON `gserver`.`id` = contact.`gsid`
2830 WHERE `contact`.`uid` = 0;
2833 -- VIEW account-user-view
2835 DROP VIEW IF EXISTS `account-user-view`;
2836 CREATE VIEW `account-user-view` AS SELECT
2837 `ucontact`.`id` AS `id`,
2838 `contact`.`id` AS `pid`,
2839 `ucontact`.`uid` AS `uid`,
2840 `contact`.`url` AS `url`,
2841 `contact`.`nurl` AS `nurl`,
2842 `contact`.`uri-id` AS `uri-id`,
2843 `item-uri`.`guid` AS `guid`,
2844 `contact`.`addr` AS `addr`,
2845 `contact`.`alias` AS `alias`,
2846 `contact`.`name` AS `name`,
2847 `contact`.`nick` AS `nick`,
2848 `contact`.`about` AS `about`,
2849 `contact`.`keywords` AS `keywords`,
2850 `contact`.`xmpp` AS `xmpp`,
2851 `contact`.`matrix` AS `matrix`,
2852 `contact`.`avatar` AS `avatar`,
2853 `contact`.`photo` AS `photo`,
2854 `contact`.`thumb` AS `thumb`,
2855 `contact`.`micro` AS `micro`,
2856 `contact`.`header` AS `header`,
2857 `contact`.`created` AS `created`,
2858 `contact`.`updated` AS `updated`,
2859 `ucontact`.`self` AS `self`,
2860 `ucontact`.`remote_self` AS `remote_self`,
2861 `ucontact`.`rel` AS `rel`,
2862 `contact`.`network` AS `network`,
2863 `ucontact`.`protocol` AS `protocol`,
2864 `contact`.`location` AS `location`,
2865 `ucontact`.`attag` AS `attag`,
2866 `contact`.`pubkey` AS `pubkey`,
2867 `contact`.`prvkey` AS `prvkey`,
2868 `contact`.`subscribe` AS `subscribe`,
2869 `contact`.`last-update` AS `last-update`,
2870 `contact`.`success_update` AS `success_update`,
2871 `contact`.`failure_update` AS `failure_update`,
2872 `contact`.`failed` AS `failed`,
2873 `contact`.`last-item` AS `last-item`,
2874 `contact`.`last-discovery` AS `last-discovery`,
2875 `contact`.`contact-type` AS `contact-type`,
2876 `contact`.`manually-approve` AS `manually-approve`,
2877 `contact`.`unsearchable` AS `unsearchable`,
2878 `contact`.`sensitive` AS `sensitive`,
2879 `contact`.`baseurl` AS `baseurl`,
2880 `contact`.`gsid` AS `gsid`,
2881 `ucontact`.`info` AS `info`,
2882 `contact`.`bdyear` AS `bdyear`,
2883 `contact`.`bd` AS `bd`,
2884 `contact`.`poco` AS `poco`,
2885 `contact`.`name-date` AS `name-date`,
2886 `contact`.`uri-date` AS `uri-date`,
2887 `contact`.`avatar-date` AS `avatar-date`,
2888 `contact`.`term-date` AS `term-date`,
2889 `contact`.`hidden` AS `global-ignored`,
2890 `contact`.`blocked` AS `global-blocked`,
2891 `ucontact`.`hidden` AS `hidden`,
2892 `ucontact`.`archive` AS `archive`,
2893 `ucontact`.`pending` AS `pending`,
2894 `ucontact`.`deleted` AS `deleted`,
2895 `ucontact`.`notify_new_posts` AS `notify_new_posts`,
2896 `ucontact`.`fetch_further_information` AS `fetch_further_information`,
2897 `ucontact`.`ffi_keyword_denylist` AS `ffi_keyword_denylist`,
2898 `ucontact`.`rating` AS `rating`,
2899 `ucontact`.`readonly` AS `readonly`,
2900 `ucontact`.`blocked` AS `blocked`,
2901 `ucontact`.`block_reason` AS `block_reason`,
2902 `ucontact`.`subhub` AS `subhub`,
2903 `ucontact`.`hub-verify` AS `hub-verify`,
2904 `ucontact`.`reason` AS `reason`,
2905 `contact`.`notify` AS `dfrn-notify`,
2906 `contact`.`poll` AS `dfrn-poll`,
2907 `item-uri`.`guid` AS `diaspora-guid`,
2908 `diaspora-contact`.`batch` AS `diaspora-batch`,
2909 `diaspora-contact`.`notify` AS `diaspora-notify`,
2910 `diaspora-contact`.`poll` AS `diaspora-poll`,
2911 `diaspora-contact`.`alias` AS `diaspora-alias`,
2912 `diaspora-contact`.`interacting_count` AS `diaspora-interacting_count`,
2913 `diaspora-contact`.`interacted_count` AS `diaspora-interacted_count`,
2914 `diaspora-contact`.`post_count` AS `diaspora-post_count`,
2915 `apcontact`.`uuid` AS `ap-uuid`,
2916 `apcontact`.`type` AS `ap-type`,
2917 `apcontact`.`following` AS `ap-following`,
2918 `apcontact`.`followers` AS `ap-followers`,
2919 `apcontact`.`inbox` AS `ap-inbox`,
2920 `apcontact`.`outbox` AS `ap-outbox`,
2921 `apcontact`.`sharedinbox` AS `ap-sharedinbox`,
2922 `apcontact`.`generator` AS `ap-generator`,
2923 `apcontact`.`following_count` AS `ap-following_count`,
2924 `apcontact`.`followers_count` AS `ap-followers_count`,
2925 `apcontact`.`statuses_count` AS `ap-statuses_count`,
2926 `gserver`.`site_name` AS `site_name`,
2927 `gserver`.`platform` AS `platform`,
2928 `gserver`.`version` AS `version`
2929 FROM `contact` AS `ucontact`
2930 INNER JOIN `contact` ON `contact`.`uri-id` = `ucontact`.`uri-id` AND `contact`.`uid` = 0
2931 LEFT JOIN `item-uri` ON `item-uri`.`id` = `ucontact`.`uri-id`
2932 LEFT JOIN `apcontact` ON `apcontact`.`uri-id` = `ucontact`.`uri-id`
2933 LEFT JOIN `diaspora-contact` ON `diaspora-contact`.`uri-id` = `ucontact`.`uri-id`
2934 LEFT JOIN `gserver` ON `gserver`.`id` = contact.`gsid`;
2937 -- VIEW pending-view
2939 DROP VIEW IF EXISTS `pending-view`;
2940 CREATE VIEW `pending-view` AS SELECT
2941 `register`.`id` AS `id`,
2942 `register`.`hash` AS `hash`,
2943 `register`.`created` AS `created`,
2944 `register`.`uid` AS `uid`,
2945 `register`.`password` AS `password`,
2946 `register`.`language` AS `language`,
2947 `register`.`note` AS `note`,
2948 `contact`.`self` AS `self`,
2949 `contact`.`name` AS `name`,
2950 `contact`.`url` AS `url`,
2951 `contact`.`micro` AS `micro`,
2952 `user`.`email` AS `email`,
2953 `contact`.`nick` AS `nick`
2955 INNER JOIN `contact` ON `register`.`uid` = `contact`.`uid`
2956 INNER JOIN `user` ON `register`.`uid` = `user`.`uid`;
2959 -- VIEW tag-search-view
2961 DROP VIEW IF EXISTS `tag-search-view`;
2962 CREATE VIEW `tag-search-view` AS SELECT
2963 `post-tag`.`uri-id` AS `uri-id`,
2964 `post-user`.`uid` AS `uid`,
2965 `post-user`.`id` AS `iid`,
2966 `post-user`.`private` AS `private`,
2967 `post-user`.`wall` AS `wall`,
2968 `post-user`.`origin` AS `origin`,
2969 `post-user`.`global` AS `global`,
2970 `post-user`.`gravity` AS `gravity`,
2971 `post-user`.`received` AS `received`,
2972 `post-user`.`network` AS `network`,
2973 `post-user`.`author-id` AS `author-id`,
2974 `tag`.`name` AS `name`
2976 INNER JOIN `tag` ON `tag`.`id` = `post-tag`.`tid`
2977 STRAIGHT_JOIN `post-user` ON `post-user`.`uri-id` = `post-tag`.`uri-id`
2978 WHERE `post-tag`.`type` = 1;
2981 -- VIEW workerqueue-view
2983 DROP VIEW IF EXISTS `workerqueue-view`;
2984 CREATE VIEW `workerqueue-view` AS SELECT
2985 `process`.`pid` AS `pid`,
2986 `workerqueue`.`priority` AS `priority`
2988 INNER JOIN `workerqueue` ON `workerqueue`.`pid` = `process`.`pid`
2989 WHERE NOT `workerqueue`.`done`;
2992 -- VIEW profile_field-view
2994 DROP VIEW IF EXISTS `profile_field-view`;
2995 CREATE VIEW `profile_field-view` AS SELECT
2996 `profile_field`.`id` AS `id`,
2997 `profile_field`.`uid` AS `uid`,
2998 `profile_field`.`label` AS `label`,
2999 `profile_field`.`value` AS `value`,
3000 `profile_field`.`order` AS `order`,
3001 `profile_field`.`psid` AS `psid`,
3002 `permissionset`.`allow_cid` AS `allow_cid`,
3003 `permissionset`.`allow_gid` AS `allow_gid`,
3004 `permissionset`.`deny_cid` AS `deny_cid`,
3005 `permissionset`.`deny_gid` AS `deny_gid`,
3006 `profile_field`.`created` AS `created`,
3007 `profile_field`.`edited` AS `edited`
3008 FROM `profile_field`
3009 INNER JOIN `permissionset` ON `permissionset`.`id` = `profile_field`.`psid`;
3012 -- VIEW diaspora-contact-view
3014 DROP VIEW IF EXISTS `diaspora-contact-view`;
3015 CREATE VIEW `diaspora-contact-view` AS SELECT
3016 `diaspora-contact`.`uri-id` AS `uri-id`,
3017 `item-uri`.`uri` AS `url`,
3018 `item-uri`.`guid` AS `guid`,
3019 `diaspora-contact`.`addr` AS `addr`,
3020 `diaspora-contact`.`alias` AS `alias`,
3021 `diaspora-contact`.`nick` AS `nick`,
3022 `diaspora-contact`.`name` AS `name`,
3023 `diaspora-contact`.`given-name` AS `given-name`,
3024 `diaspora-contact`.`family-name` AS `family-name`,
3025 `diaspora-contact`.`photo` AS `photo`,
3026 `diaspora-contact`.`photo-medium` AS `photo-medium`,
3027 `diaspora-contact`.`photo-small` AS `photo-small`,
3028 `diaspora-contact`.`batch` AS `batch`,
3029 `diaspora-contact`.`notify` AS `notify`,
3030 `diaspora-contact`.`poll` AS `poll`,
3031 `diaspora-contact`.`subscribe` AS `subscribe`,
3032 `diaspora-contact`.`searchable` AS `searchable`,
3033 `diaspora-contact`.`pubkey` AS `pubkey`,
3034 `gserver`.`url` AS `baseurl`,
3035 `diaspora-contact`.`gsid` AS `gsid`,
3036 `diaspora-contact`.`created` AS `created`,
3037 `diaspora-contact`.`updated` AS `updated`,
3038 `diaspora-contact`.`interacting_count` AS `interacting_count`,
3039 `diaspora-contact`.`interacted_count` AS `interacted_count`,
3040 `diaspora-contact`.`post_count` AS `post_count`
3041 FROM `diaspora-contact`
3042 INNER JOIN `item-uri` ON `item-uri`.`id` = `diaspora-contact`.`uri-id`
3043 LEFT JOIN `gserver` ON `gserver`.`id` = `diaspora-contact`.`gsid`;