Database schema

This commit is contained in:
Shashi Gowda 2011-03-06 23:26:27 +05:30
parent a127ba78a8
commit 32a00059fa
3 changed files with 124 additions and 2 deletions

4
db/095topeopletags.sql Normal file
View File

@ -0,0 +1,4 @@
/* populate people tags metadata */
insert into profile_list (tagger, tag, modified, description, private)
select distinct tagger, tag, modified, null, false from profile_tag;

View File

@ -604,8 +604,9 @@ $schema['profile_tag'] = array(
), ),
'primary key' => array('tagger', 'tagged', 'tag'), 'primary key' => array('tagger', 'tagged', 'tag'),
'foreign keys' => array( 'foreign keys' => array(
'profile_tag_tagger_fkey' => array('user', array('tagger' => 'id')), 'profile_tag_tagger_fkey' => array('profile', array('tagger' => 'id')),
'profile_tag_tagged_fkey' => array('profile', array('tagged' => 'id')), 'profile_tag_tagged_fkey' => array('profile', array('tagged' => 'id')),
'profile_tag_tag_fkey' => array('profile_list', array('tag' => 'tag')),
), ),
'indexes' => array( 'indexes' => array(
'profile_tag_modified_idx' => array('modified'), 'profile_tag_modified_idx' => array('modified'),
@ -614,6 +615,76 @@ $schema['profile_tag'] = array(
), ),
); );
$schema['profile_list'] = array(
'fields' => array(
'id' => array('type' => 'serial', 'not null' => true, 'description' => 'unique identifier'),
'tagger' => array('type' => 'int', 'not null' => true, 'description' => 'user making the tag'),
'tag' => array('type' => 'varchar', 'length' => 64, 'not null' => true, 'description' => 'people tag'),
'description' => array('type' => 'text', 'description' => 'description of the people tag'),
'private' => array('type' => 'int', 'size' => 'tiny', 'default' => 0, 'description' => 'is this tag private'),
'created' => array('type' => 'timestamp', 'not null' => true, 'description' => 'date the tag was added'),
'modified' => array('type' => 'timestamp', 'not null' => true, 'description' => 'date the tag was modified'),
'uri' => array('type' => 'varchar', 'length' => 255, 'description' => 'universal identifier'),
'mainpage' => array('type' => 'varchar', 'length' => 255, 'description' => 'page to link to'),
'tagged_count' => array('type' => 'int', 'default' => 0, 'description' => 'number of people tagged with this tag by this user'),
'subscriber_count' => array('type' => 'int', 'default' => 0, 'description' => 'number of subscribers to this tag'),
),
'primary key' => array('tagger', 'tag'),
'unique keys' => array(
'profile_list_id_key' => array('id')
),
'foreign keys' => array(
'profile_list_tagger_fkey' => array('profile', array('tagger' => 'id')),
),
'indexes' => array(
'profile_list_modified_idx' => array('modified'),
'profile_list_tag_idx' => array('tag'),
'profile_list_tagger_tag_idx' => array('tagger', 'tag'),
'profile_list_tagged_count_idx' => array('tagged_count'),
'profile_list_subscriber_count_idx' => array('subscriber_count'),
),
);
$schema['profile_tag_inbox'] = array(
'description' => 'Many-many table listing notices associated with people tags.',
'fields' => array(
'profile_tag_id' => array('type' => 'int', 'not null' => true, 'description' => 'people tag receiving the message'),
'notice_id' => array('type' => 'int', 'not null' => true, 'description' => 'notice received'),
'created' => array('type' => 'datetime', 'not null' => true, 'description' => 'date the notice was created'),
),
'primary key' => array('profile_tag_id', 'notice_id'),
'foreign keys' => array(
'profile_tag_inbox_profile_list_id_fkey' => array('profile_list', array('profile_tag_id' => 'id')),
'profile_tag_inbox_notice_id_fkey' => array('notice', array('notice_id' => 'id')),
),
'indexes' => array(
'profile_tag_inbox_created_idx' => array('created'),
'profile_tag_inbox_profile_tag_id_idx' => array('profile_tag_id'),
),
);
$schema['profile_tag_subscription'] = array(
'fields' => array(
'profile_tag_id' => array('type' => 'int', 'not null' => true, 'description' => 'foreign key to profile_tag'),
'profile_id' => array('type' => 'int', 'not null' => true, 'description' => 'foreign key to profile table'),
'created' => array('type' => 'datetime', 'not null' => true, 'description' => 'date this record was created'),
'modified' => array('type' => 'timestamp', 'not null' => true, 'description' => 'date this record was modified'),
),
'primary key' => array('profile_tag_id', 'profile_id'),
'foreign keys' => array(
'profile_tag_subscription_profile_list_id_fkey' => array('profile_list', array('profile_tag_id' => 'id')),
'profile_tag_subscription_profile_id_fkey' => array('profile', array('profile_id' => 'id')),
),
'indexes' => array(
// @fixme probably we want a (profile_id, created) index here?
'profile_tag_subscription_profile_id_idx' => array('profile_id'),
'profile_tag_subscription_created_idx' => array('created'),
),
);
$schema['profile_block'] = array( $schema['profile_block'] = array(
'fields' => array( 'fields' => array(
'blocker' => array('type' => 'int', 'not null' => true, 'description' => 'user making the block'), 'blocker' => array('type' => 'int', 'not null' => true, 'description' => 'user making the block'),

View File

@ -403,7 +403,7 @@ create table notice_inbox (
) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin; ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
create table profile_tag ( create table profile_tag (
tagger integer not null comment 'user making the tag' references user (id), tagger integer not null comment 'user making the tag' references profile (id),
tagged integer not null comment 'profile tagged' references profile (id), tagged integer not null comment 'profile tagged' references profile (id),
tag varchar(64) not null comment 'hash tag associated with this notice', tag varchar(64) not null comment 'hash tag associated with this notice',
modified timestamp comment 'date the tag was added', modified timestamp comment 'date the tag was added',
@ -414,6 +414,53 @@ create table profile_tag (
index profile_tag_tagged_idx (tagged) index profile_tag_tagged_idx (tagged)
) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin; ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
/* people tag metadata */
create table profile_list (
id integer auto_increment unique key comment 'unique identifier',
tagger integer not null comment 'user making the tag' references profile (id),
tag varchar(64) not null comment 'hash tag',
description text comment 'description for the tag',
private tinyint(1) default 0 comment 'is this list private',
created datetime not null comment 'date this record was created',
modified timestamp comment 'date this record was modified',
uri varchar(255) unique key comment 'universal identifier',
mainpage varchar(255) comment 'page for tag info info to link to',
tagged_count smallint not null default 0 comment 'number of people tagged',
subscriber_count smallint not null default 0 comment 'number of people subscribing',
constraint primary key (tagger, tag),
index profile_list_tag_idx (tag),
index profile_list_tagged_count_idx (tagged_count),
index profile_list_modified_idx (modified),
index profile_list_subscriber_count_idx (subscriber_count)
) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
create table profile_tag_inbox (
profile_tag_id integer not null comment 'peopletag receiving the message' references profile_tag (id),
notice_id integer not null comment 'notice received' references notice (id),
created datetime not null comment 'date the notice was created',
constraint primary key (profile_tag_id, notice_id),
index profile_tag_inbox_created_idx (created),
index profile_tag_inbox_notice_id_idx (notice_id)
) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
create table profile_tag_subscription (
profile_tag_id integer not null comment 'foreign key to profile_tag' references profile_list (id),
profile_id integer not null comment 'foreign key to profile table' references profile (id),
created datetime not null comment 'date this record was created',
modified timestamp comment 'date this record was modified',
constraint primary key (profile_tag_id, profile_id),
index profile_tag_subscription_profile_id_idx (profile_id),
index profile_tag_subscription_created_idx (created)
) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
create table profile_block ( create table profile_block (
blocker integer not null comment 'user making the block' references user (id), blocker integer not null comment 'user making the block' references user (id),
blocked integer not null comment 'profile that is blocked' references profile (id), blocked integer not null comment 'profile that is blocked' references profile (id),