CREATE TABLE Channel (
-- The channel id, primary key.
cid SERIAL PRIMARY KEY,
-- The name of the channel.
name VARCHAR(50) UNIQUE NOT NULL,
-- The icecast mount point, starts with a /
path VARCHAR(50) UNIQUE NOT NULL,
-- Is this channel a "real" channel?
isreal SMALLINT NOT NULL DEFAULT 1,
-- A description of the channel for listeners to see.
description TEXT NOT NULL,
-- A description of the channel for DJs to see.
djdescription TEXT NOT NULL
);
The Channel table holds all the channels in the system. Each channel
corresponds one-to-one with an icecast mount point. The isreal field
determines if karma points are calculated for broadcasts on the
channel. Example: the OPENdj practice channel is not a "real"
channel, so anything a DJ broadcasts on the practice channel will not
affect their karma.
CREATE TABLE Dj (
-- The DJ id, primary key.
djid SERIAL PRIMARY KEY,
-- The DJ's genre.
genre INTEGER NOT NULL,
-- The date this DJ joined OPENdj
-- (milliseconds value from System.getCurrentTimeMillis)
joindate BIGINT DEFAULT NULL,
-- The date this DJ first broadcasted a show
-- (milliseconds value from System.getCurrentTimeMillis)
firstbroadcast BIGINT DEFAULT NULL,
-- The total number of broadcasts this DJ has done, not including reruns
numbroadcasts INTEGER NOT NULL DEFAULT 0,
-- The total number of listeners this DJ has had.
totallisteners INTEGER NOT NULL DEFAULT 0,
-- The number of times this DJ has substituted for another DJ
numsubs INTEGER NOT NULL DEFAULT 0,
-- The number of comments this DJ has received in the chat room
-- during broadcasts (not currently implemented)
numcomments INTEGER NOT NULL DEFAULT 0,
-- What the heck is this? Isn't this already captured
-- in numbroadcasts? Oh well, I need to figure out why
-- I created this column.... it's not currently used anywhere
-- in the code.
numshows INTEGER NOT NULL DEFAULT 0,
-- The number of reruns this DJ has scheduled. This does not
-- count reruns that the system schedules to fill up empty time.
numreruns INTEGER NOT NULL DEFAULT 0,
-- The number of times this DJ has arrived late for a broadcast.
numstartlate INTEGER NOT NULL DEFAULT 0,
-- The number of times this DJ has left early for a broadcast.
numendearly INTEGER NOT NULL DEFAULT 0,
-- The number of times this DJ has completely not showed up for a broadcast.
numnoshow INTEGER NOT NULL DEFAULT 0,
-- The maximum number of broadcasting "blocks" that this
-- DJ is allowed to schedule weekly broadcasts.
maxweeklyblocks INTEGER NOT NULL DEFAULT 32,
-- The maximum number of broadcasting "blocks" that this
-- DJ is allowed to schedule one-time broadcasts.
maxsingleblocks INTEGER NOT NULL DEFAULT 64,
-- The DJ's karma score.
karma BIGINT NOT NULL DEFAULT 0,
-- The DJ's most recently used IP address. Needed to
-- configure the firewall access in DJServer.
ipaddr VARCHAR(20) NOT NULL,
-- The DJ's email address.
email VARCHAR(100) UNIQUE NOT NULL,
-- The DJ's password, stored as the base64-encoded MD5
-- hash of their password.
password VARCHAR(100),
-- The DJ's show name.
showname VARCHAR(100) UNIQUE,
-- The DJ's DJ name.
djname VARCHAR(100) UNIQUE,
-- The city where the DJ lives.
city VARCHAR(100),
-- The state or province where the DJ lives.
state VARCHAR(20),
-- The country where the DJ lives.
country VARCHAR(80),
-- The DJ's phone number.
phone VARCHAR(20),
-- The DJ's description of their own music/programming.
musicdesc TEXT,
-- The DJ's web page.
webpage TEXT,
CONSTRAINT fk_dj_genre FOREIGN KEY (genre) REFERENCES Genre(gid)
);
Notes:
The genre assigned to broadcasts that this DJ makes will be the genre
referenced by the "genre" field. DJs can override this by updating
their show meta-data while the broadcast is in progress.
The totallisteners column is calculated like so: each broadcast, add
the average number of listeners for that show to the total.
The Dj table is the main "user" table in OPENdj. All registered DJs
have an entry in the Dj table. The djid #1 is usually reserved for the
"rerun" DJ (a pseudo-DJ who connects to the DJServer to broadcast reruns).
CREATE TABLE ScheduleBlock (
-- The block id, primary key.
bid SERIAL PRIMARY KEY,
-- The channel id, foreign key into Channel table.
-- Specifies that channel that this block applies to.
channelid INTEGER NOT NULL,
-- The day of week (0-6, 0=Sunday) that this block applies to.
day SMALLINT NOT NULL,
-- Attributes of this block.
attributes INTEGER NOT NULL DEFAULT 0,
-- When this block starts - expressed as the integer number
-- of minutes past midnight (0-1425), must be a multiple of 15.
starttime INTEGER NOT NULL DEFAULT 0,
CONSTRAINT fk_scheduleblock_channelid FOREIGN KEY (channelid) REFERENCES Channel(cid)
);
The OPENdj schedule is broken down into ScheduleBlocks of 15 minutes
in length each. Each channel has a full compliment of 672 schedule
blocks to cover every day of the week.
That is 96 blocks per day (there are 1440 minutes in a day, divide by
15 because each block is 15 minutes long), and there are 7 days in a
week, so 96 * 7 = 672.
The attributes field determines the scheduling behavior of the block
and is the primary reason for the existence of this table - it
determines what can be scheduled when on any channel in the OPENdj
system.
The attributes field is interpreted in a bitwise manner. There are
ATTR_XXX constants in the org.opendj.util.SchedBlock class (in
opendj-servercommon project) that you can bitwise OR together to
create the attributes. The meaning of the bits of the attributes
field is:
LSB (bit 0): If 0, this block is unmoderated. If 1, this block is
moderated Note that moderation is not yet supported, so currently
this bit does nothing.
(bit 1): If 0, this block may only be scheduled for a weekly
broadcast. If 1, this block may only be scheduled for one-time
broadcasts.
(bit 2): Only applies if bit 1 is 1. If 1, this block can be
used by a weekly-broadcast, even though it is marked as reserved
for one-time broadcasts by bit 1. If 0, this block cannot be used by
weekly broadcasts, and can only be used by one-time broadcasts. This
is not currently implemented.
(bit 3): I call this the "SUBDJ" bit, but I forget what the heck it is
supposed to do. In the code it is never used.
(bit 4 - MSB): Reserved.
CREATE TABLE Scheduled (
-- The scheduled id, primary key.
sid SERIAL PRIMARY KEY,
-- The block id that this scheduled block applies to.
-- References bid in the ScheduleBlock table.
bid INTEGER NOT NULL,
-- The DJ who has scheduled this block.
-- References djid in the Dj table.
djid INTEGER NOT NULL DEFAULT 1,
-- Is this a one-time broadcast?
issingle SMALLINT DEFAULT 0,
-- If this is a onetime broadcast, this is the date
-- of the broadcast.
singledate DATE NOT NULL,
-- If this is a weekly broadcast, this is the date
-- of the first broadcast.
startlease DATE,
-- If this is a weekly broadcast, this is the date
-- of the last broadcast.
endlease DATE,
-- Is this slot active? This is not currently used.
isactive SMALLINT NOT NULL,
-- Has this slot been published in the published schedule table?
ispublished SMALLINT NOT NULL,
CONSTRAINT fk_scheduled_bid FOREIGN KEY (bid) REFERENCES ScheduleBlock(bid),
CONSTRAINT fk_scheduled_djid FOREIGN KEY (djid) REFERENCES Dj(djid)
);
The Scheduled table represents everything that has been scheduled for
broadcast. When someone signs up for a broadcast, the
CREATE TABLE ArchivedShow (
-- The archive id, primary key.
archid SERIAL PRIMARY KEY,
-- The DJ who originally broadcasted the show that
-- is this archive
djid INTEGER NOT NULL,
-- The genre assigned to the archive, references the
-- gid field of the Genre table.
genre INTEGER NOT NULL,
-- The mood assigned to the archive, references the
-- mid field of the Mood table.
djmood INTEGER NOT NULL DEFAULT 1,
-- The scheduled start time of the broadcast,
-- in a milliseconds value (like something you'd get from
-- System.currentTimeMillis)
starttime BIGINT NOT NULL,
-- The time the broadcast actually did start.
actualstart BIGINT,
-- The time the broadcast ended.
endtime BIGINT NOT NULL,
-- The last time this broadcast was aired.
lastaired BIGINT NOT NULL,
-- The channel that this broadcast was originally done on.
-- References the cid field of the Channel table.
channelid INTEGER NOT NULL,
-- The average number of listeners that originally tuned in
-- to this broadcast.
numlisteners INTEGER NOT NULL DEFAULT 0,
-- The number of comments that appeared in the chat room
-- during this broadcast (not currently implemented).
numcomments INTEGER NOT NULL DEFAULT 0,
-- The bitrate that this broadcast was originally done at.
bitrate INTEGER NOT NULL DEFAULT 0,
-- Ratings values - not currently implemented.
rconntotal INTEGER NOT NULL DEFAULT 0,
rconncount INTEGER NOT NULL DEFAULT 0,
rconnavg INTEGER NOT NULL DEFAULT 0,
raudiototal INTEGER NOT NULL DEFAULT 0,
raudiocount INTEGER NOT NULL DEFAULT 0,
raudioavg INTEGER NOT NULL DEFAULT 0,
rstyletotal INTEGER NOT NULL DEFAULT 0,
rstylecount INTEGER NOT NULL DEFAULT 0,
rstyleavg INTEGER NOT NULL DEFAULT 0,
-- Was the archive successfully completed?
iscompleted SMALLINT NOT NULL DEFAULT 0,
-- Not currently used, this would mark certain archives
-- as special so they would not be deleted if disk space
-- got tight from too many archives.
iskeeper SMALLINT NOT NULL DEFAULT 0,
-- Is this an archive that can be scheduled as a rerun?
isrerunnable SMALLINT NOT NULL DEFAULT 0,
-- How much karma did the DJ earn when broadcasting this?
karmaearned INTEGER NOT NULL DEFAULT 0,
-- The name of the mood. Copied from the Mood table.
moodval VARCHAR(50),
-- The name of the genre. Copied from the Genre table.
genreval VARCHAR(50),
-- The name of the DJ. Copied from the Dj table.
djname VARCHAR(100),
-- The name of the DJ's show. Copied from the Dj table.
showname VARCHAR(100),
-- The absolute filesystem path to the archive.
showfile VARCHAR(255),
-- The URL (relative to the main icecast url) for the show
showurl VARCHAR(255),
-- Not used. Could be used to point to a page containing
-- a transcript of everything that was said in the chat room.
transcripturl VARCHAR(255),
-- The DJ's comments about this show.
djcomments TEXT,
CONSTRAINT fk_archivedshow_djid FOREIGN KEY (djid) REFERENCES Dj(djid),
CONSTRAINT fk_archivedshow_genre FOREIGN KEY (genre) REFERENCES Genre(gid),
CONSTRAINT fk_archivedshow_djmood FOREIGN KEY (djmood) REFERENCES Mood(mid),
CONSTRAINT fk_archivedshow_channelid FOREIGN KEY (channelid) REFERENCES Channel(cid)
);
The ArchivedShow table contains records of all broadcasts that have
been archived. There must be one "empty" row in this table with
archid = 1. The contents of this row are irrelevant, but it must be
there for certain parts of the system to work.
CREATE TABLE PublishedSchedule (
-- The primary key.
psid SERIAL PRIMARY KEY,
-- The channel this was published on.
-- References cid in the Channel table.
channelid INTEGER NOT NULL,
-- The DJ who will broadcast this show.
-- References djid in the Dj table.
djid INTEGER NOT NULL,
-- The "effective" DJ id (more info below)
-- References djid in the Dj table.
edjid INTEGER NOT NULL,
-- The genre of this show.
-- References gid in the Genre table.
genre INTEGER NOT NULL,
-- When this show starts (millisecond value)
starttime BIGINT NOT NULL,
-- When this show ends (millisecond value)
endtime BIGINT NOT NULL,
-- The status of this show (see info below)
status SMALLINT NOT NULL DEFAULT 0,
-- If this show is part of a series of weekly
-- broadcasts, this is the number of weeks that
-- were committed to.
numweeks INTEGER NOT NULL DEFAULT 0,
-- If this showis a rerun, this is the archive id
-- of the previously broadcast show. References archid
-- in the ArchivedShow table.
archid INTEGER NOT NULL DEFAULT 1,
-- The name of the channel that this will be broadcast
-- on. Copied from the Channel table.
channelname VARCHAR(50) NOT NULL,
-- The path of the channel that this will be broadcast
-- on. Copied from the Channel table.
channelpath VARCHAR(50) NOT NULL,
-- The IP addresses that is expected for this broadcast.
-- Used when configuring the firewall in DJServer.
ipaddr VARCHAR(20) NOT NULL,
-- The DJ's email address. Copied from the Dj table.
djemail VARCHAR(100) NOT NULL,
-- The DJ's DJ name. Copied from the Dj table.
djname VARCHAR(100) NOT NULL,
-- The DJ's show name. Copied from the Dj table.
showname VARCHAR(100) NOT NULL,
-- The name of the genre. Copied from the Genre table.
genreval VARCHAR(50) NOT NULL,
CONSTRAINT fk_publishedschedule_channelid FOREIGN KEY (channelid) REFERENCES Channel(cid),
CONSTRAINT fk_publishedschedule_djid FOREIGN KEY (djid) REFERENCES Dj(djid),
CONSTRAINT fk_publishedschedule_edjid FOREIGN KEY (edjid) REFERENCES Dj(djid),
CONSTRAINT fk_publishedschedule_genre FOREIGN KEY (genre) REFERENCES Genre(gid),
CONSTRAINT fk_publishedschedule_archid FOREIGN KEY (archid) REFERENCES ArchivedShow(archid)
);
NOTES:
The edjid field is used in rerun and subsititute DJ situations. When
a rerun is being broadcast, the djid field will always be the djid of
the "rerun DJ", a special DJ account that can automatically broadcast
reruns. So when a rerun is on, the edjid field contains the djid of
the DJ who originally did the broadcast that is being rerun. In a
substitute DJ situation, the djid field holds the djid of the DJ who
is being the substitute, while the edjid field hols the djid of the
original DJ who requested the substitute.
The status field indicates the status of the entry.
The valid values are:
0 - The DJ (djid) scheduled the slot.
1 - The DJ (djid) has requested a sub for this show. This means that
another DJ can take the show, thus overwriting the djid field with
their own. This would then move the current DJ's djid into the edjid
field.
2 - The DJ (djid) is substituting for the DJ's whose djid is in the
edjid field.
3 - The DJ (djid) has requested a sub for this show, but if no sub
volunteers, a rerun of a previous broadcast will be streamed
instead.
4 - The DJ has scheduled a rerun to be broadcast instead of doing a
live show. The archid field contains the archid of the rerun to
broadcast. The djid holds the djid of the "rerun DJ", and the edjid
holds the djid of the original DJ.
5 - The OPENdj system has scheduled a rerun in this space, which would
otherwise be dead air. The archid field contains the archid of
the rerun to broadcast. The djid holds the djid of the "rerun DJ",
and the edjid holds the djid of the original DJ.
Whereas the Scheduled table is block-oriented, the PublishedSchedule
is absolute-time oriented. You consult the Scheduled table to
see if blocks are available to schedule, but you use the
PublishedSchedule table when you actually need to render a schedule
for listeners. The reason? Rendering a schedule using the Scheduled
table requires some fancy outer-joins with the ScheduleBlock table and
could be horribly inefficient in a high-traffic environment.
Rendering a schedule with the Published schedule table is very fast,
especially since many of the "join" fields are copied right into the
table (djname, genreval, etc).
CREATE TABLE OnAirStatus (
-- The published schedule id - one-to-one mapping
-- with psid from PublishedSchedule table.
psid INTEGER UNIQUE NOT NULL,
-- The bitrate that is actually being streamed.
bitrate INTEGER NOT NULL DEFAULT 0,
-- The DJ that is actually broadcasting.
-- References the djid field in the Dj table.
djid INTEGER NOT NULL,
-- The "effective" DJ id.
-- References the djid field in the Dj table.
edjid INTEGER NOT NULL,
-- The time the broadcast started.
starttime BIGINT NOT NULL,
-- The time the broadcast ended.
endtime BIGINT NOT NULL,
-- If this is a weekly broadcast, this holds the
-- number of weeks that were originally committed to.
numweeks INTEGER NOT NULL DEFAULT 0,
-- The status (same as in PublishedSchedule, see above)
status SMALLINT NOT NULL DEFAULT 0,
-- When the DJ first arrived on the air
onairtime BIGINT NOT NULL DEFAULT 0,
-- The last (most recent) time that the system
-- noticed the DJ was still on the air.
lastonairtime BIGINT NOT NULL DEFAULT 0,
-- The last time the system took a "sample" of
-- the broadcast.
lastsampletime BIGINT NOT NULL DEFAULT 0,
-- The number of samples that have been taken.
samplecount INTEGER NOT NULL DEFAULT 0,
-- The number of times the DJ has been on the air
-- when samples were taken (ergo must be <= samplecount).
onaircount INTEGER NOT NULL DEFAULT 0,
-- The total number of listeners, taken as the sum
-- of the instantaneous number of listeners at every
-- sample interval
listenercount INTEGER NOT NULL DEFAULT 0,
-- The instantaneous number of listeners that were
-- listening when the last sample was taken.
recentlcount INTEGER NOT NULL DEFAULT 0,
-- The path of the channel that the show is on.
-- Copied from the Channel table.
channelpath VARCHAR(50) PRIMARY KEY,
CONSTRAINT fk_onairstatus_psid FOREIGN KEY (psid) REFERENCES PublishedSchedule(psid),
CONSTRAINT fk_onairstatus_djid FOREIGN KEY (djid) REFERENCES Dj(djid),
CONSTRAINT fk_onairstatus_edjid FOREIGN KEY (edjid) REFERENCES Dj(djid),
CONSTRAINT fk_onairstatus_channelpath FOREIGN KEY (channelpath) REFERENCES Channel(path)
);
There is (at most) one row in the OnAirStatus table for each channel. Each
channel-specific row holds information about the current live
broadcast. Think of this table as a scratch pad that the OPENdj
system uses for accounting purposes during a show. The information in
this table is used in several places. For one, the "recentlcount"
field is used on the main "listen" page to tell site visitors how many
people are currently listening to a stream. Many of the other fields
are used to calculate karma after a show has completed.
CREATE TABLE ChatRoom (
-- The name of the room. Primary key.
roomname VARCHAR(50) PRIMARY KEY,
-- The maximum number of chatters allowed in the room.
maxchatters INTEGER NOT NULL DEFAULT 100,
-- Is the room public? If 0, then this
-- room is only open to registered DJs (of course,
-- anyone can register!)
ispublic SMALLINT DEFAULT 0,
-- This holds the djid of the moderator. The moderator
-- can boot people from the chat. See the ODCP spec for
-- more info.
moderatordjid INTEGER DEFAULT NULL,
-- A description of the chat room.
description VARCHAR(200) DEFAULT NULL
);
Pretty straightforward - there's a row in the ChatRoom table for each
chat room that exists. By default, there's one chat room for each
channel, and one chat room in the DJZone area which is reserved for
DJs only.
CREATE TABLE ChatComments (
-- Primary key
commentid SERIAL PRIMARY KEY,
-- The archive that this chat refers to.
-- References the archid field in ArchivedShow.
archid INTEGER NOT NULL DEFAULT 0,
-- Time that this was posted.
posted BIGINT NOT NULL,
-- The chat room that this comment was made in
roomname VARCHAR(50) NOT NULL,
-- The name of the chatter who posted this
fromname VARCHAR(100),
-- The actual text of the message
message TEXT,
CONSTRAINT fk_chatcomments_archid FOREIGN KEY (archid) REFERENCES ArchivedShow(archid),
CONSTRAINT fk_chatcomments_roomname FOREIGN KEY (roomname) REFERENCES ChatRoom(roomname)
);
This table holds all of the public comments that were made in every
chat room. NOTE: private comments from one chatter to another (and
NOT public to the whole chat room) are NOT recorded here or anywhere
else. The archid is only filled out if the comments were made in a
chat room associated with a channel that had a live broadcast on.
This is so that later, if we want, we can reconstruct a transcript of
the chat that took place during a live broadcast. Maybe people would
want to read that while they listened to the rerun.
CREATE TABLE AsyncMail (
-- Primary key.
amid SERIAL PRIMARY KEY,
-- Status of the mail
status SMALLINT NOT NULL,
-- Time the mail was queued.
queuetime BIGINT NOT NULL,
-- How many times we've had errors trying to send this.
errorcount SMALLINT NOT NULL DEFAULT 0,
-- The next time we'll try to send this.
nextsend BIGINT NOT NULL,
-- The name of the AsyncMailClient that has claimed
-- responsibility for delivering this email
client VARCHAR(20) NOT NULL,
-- Who this email is from.
fromemail VARCHAR(250) NOT NULL,
-- The subject of the email.
subject VARCHAR(250) NOT NULL,
-- The list of who this email will be delivered to.
toemails VARCHAR(255) NOT NULL,
-- The text of the email message.
message TEXT
);
All emails sent in the OPENdj system are sent asynchronously. For
example, when someone signs up to be a DJ, they get a "welcome"
email. This welcome email is inserted into the AsyncMail table. Then
an instance of org.opendj.util.mail.AsyncMailClient, running somewhere
else, handles the actual sending of the email. There can be multiple
AsyncMailClients running for scalability, perhaps on separate
machines, using separate mail servers connected to separate Internet
connections. Each AsyncMailClient claims responsibility for emails to
send by marking the "client" field. This prevents multiple
AsyncMailClients from trying to send the same email.