2 # 1) Create a database using the "CREATE DATABASE" mysql command.
3 # 2) Then, execute this script from command prompt with a command like this:
4 # mysql -h host -u user -p -D db_name < mysql.sql
6 # create database timetracker character set = 'utf8';
12 # Structure for table tt_teams. A team is a group of users for whom we are tracking work time.
13 # This table stores settings common to all team members such as language, week start day, etc.
15 CREATE TABLE `tt_teams` (
16 `id` int(11) NOT NULL auto_increment, # team id
17 `timestamp` timestamp NOT NULL, # modification timestamp
18 `name` varchar(80) default NULL, # team name
19 `address` varchar(255) default NULL, # team address, used in invoices
20 `currency` varchar(7) default NULL, # team currency symbol
21 `decimal_mark` char(1) NOT NULL default '.', # separator in decimals
22 `lang` varchar(10) NOT NULL default 'en', # language
23 `date_format` varchar(20) NOT NULL default '%Y-%m-%d', # date format
24 `time_format` varchar(20) NOT NULL default '%H:%M', # time format
25 `week_start` smallint(2) NOT NULL DEFAULT '0', # Week start day, 0 == Sunday.
26 `tracking_mode` smallint(2) NOT NULL DEFAULT '1', # tracking mode ("projects" or "projects and tasks")
27 `record_type` smallint(2) NOT NULL DEFAULT '0', # time record type ("start and finish", "duration", or both)
28 `plugins` varchar(255) default NULL, # a list of enabled plugins for team
29 `lock_spec` varchar(255) default NULL, # Cron specification for record locking,
30 # for example: "0 10 * * 1" for "weekly on Mon at 10:00".
31 `workday_hours` smallint(6) DEFAULT '8', # number of work hours in a regular day
32 `custom_logo` tinyint(4) default '0', # whether to use a custom logo or not
33 `status` tinyint(4) default '1', # team status
39 # Structure for table tt_users. This table is used to store user properties.
41 CREATE TABLE `tt_users` (
42 `id` int(11) NOT NULL auto_increment, # user id
43 `timestamp` timestamp NOT NULL, # modification timestamp
44 `login` varchar(50) COLLATE utf8_bin NOT NULL, # user login
45 `password` varchar(50) default NULL, # password hash
46 `name` varchar(100) default NULL, # user name
47 `team_id` int(11) NOT NULL, # team id
48 `role` int(11) default '4', # user role ("manager", "co-manager", "client", or "user")
49 `client_id` int(11) default NULL, # client id for "client" user role
50 `rate` float(6,2) NOT NULL default '0.00', # default hourly rate
51 `email` varchar(100) default NULL, # user email
52 `status` tinyint(4) default '1', # user status
56 # Create an index that guarantees unique active and inactive logins.
57 create unique index login_idx on tt_users(login, status);
59 # Create admin account with password 'secret'. Admin is a superuser, who can create teams.
60 DELETE from `tt_users` WHERE login = 'admin';
61 INSERT INTO `tt_users` (`login`, `password`, `name`, `team_id`, `role`) VALUES ('admin', md5('secret'), 'Admin', '0', '1024');
65 # Structure for table tt_projects.
67 CREATE TABLE `tt_projects` (
68 `id` int(11) NOT NULL auto_increment, # project id
69 `team_id` int(11) NOT NULL, # team id
70 `name` varchar(80) COLLATE utf8_bin NOT NULL, # project name
71 `description` varchar(255) default NULL, # project description
72 `tasks` text default NULL, # comma-separated list of task ids associated with this project
73 `status` tinyint(4) default '1', # project status
77 # Create an index that guarantees unique active and inactive projects per team.
78 create unique index project_idx on tt_projects(team_id, name, status);
82 # Structure for table tt_tasks.
84 CREATE TABLE `tt_tasks` (
85 `id` int(11) NOT NULL auto_increment, # task id
86 `team_id` int(11) NOT NULL, # team id
87 `name` varchar(80) COLLATE utf8_bin NOT NULL, # task name
88 `description` varchar(255) default NULL, # task description
89 `status` tinyint(4) default '1', # task status
93 # Create an index that guarantees unique active and inactive tasks per team.
94 create unique index task_idx on tt_tasks(team_id, name, status);
98 # Structure for table tt_user_project_binds. This table maps users to assigned projects.
100 CREATE TABLE `tt_user_project_binds` (
101 `id` int(11) NOT NULL auto_increment, # bind id
102 `user_id` int(11) NOT NULL, # user id
103 `project_id` int(11) NOT NULL, # project id
104 `rate` float(6,2) default '0.00', # rate for this user when working on this project
105 `status` tinyint(4) default '1', # bind status
109 # Create an index that guarantees unique user to project binds.
110 create unique index bind_idx on tt_user_project_binds(user_id, project_id);
114 # Structure for table tt_project_task_binds. This table maps projects to assigned tasks.
116 CREATE TABLE `tt_project_task_binds` (
117 `project_id` int(11) NOT NULL, # project id
118 `task_id` int(11) NOT NULL # task id
121 # Indexes for tt_project_task_binds.
122 create index project_idx on tt_project_task_binds(project_id);
123 create index task_idx on tt_project_task_binds(task_id);
127 # Structure for table tt_log. This is the table where time entries for users are stored.
128 # If you use custom fields, additional info for each record may exist in tt_custom_field_log.
130 CREATE TABLE `tt_log` (
131 `id` bigint NOT NULL auto_increment, # time record id
132 `timestamp` timestamp NOT NULL, # modification timestamp
133 `user_id` int(11) NOT NULL, # user id
134 `date` date NOT NULL, # date the record is for
135 `start` time default NULL, # record start time (for example, 09:00)
136 `duration` time default NULL, # record duration (for example, 1 hour)
137 `client_id` int(11) default NULL, # client id
138 `project_id` int(11) default NULL, # project id
139 `task_id` int(11) default NULL, # task id
140 `invoice_id` int(11) default NULL, # invoice id
141 `comment` blob, # user provided comment for time record
142 `billable` tinyint(4) default '0', # whether the record is billable or not
143 `status` tinyint(4) default '1', # time record status
147 # Create indexes on tt_log for performance.
148 create index date_idx on tt_log(date);
149 create index user_idx on tt_log(user_id);
150 create index client_idx on tt_log(client_id);
151 create index invoice_idx on tt_log(invoice_id);
152 create index project_idx on tt_log(project_id);
153 create index task_idx on tt_log(task_id);
157 # Structure for table tt_invoices. Invoices are issued to clients for billable work.
159 CREATE TABLE `tt_invoices` (
160 `id` int(11) NOT NULL auto_increment, # invoice id
161 `team_id` int(11) NOT NULL, # team id
162 `name` varchar(80) COLLATE utf8_bin NOT NULL, # invoice name
163 `date` date NOT NULL, # invoice date
164 `client_id` int(11) NOT NULL, # client id
165 `status` tinyint(4) default '1', # invoice status
169 # Create an index that guarantees unique invoice names per team.
170 create unique index name_idx on tt_invoices(team_id, name, status);
174 # Structure for table tt_tmp_refs. Used for reset password mechanism.
176 CREATE TABLE `tt_tmp_refs` (
177 `timestamp` timestamp NOT NULL, # creation timestamp
178 `ref` char(32) NOT NULL default '', # unique reference for user, used in urls
179 `user_id` int(11) NOT NULL # user id
184 # Structure for table tt_fav_reports. Favorite reports are pre-configured report configurations.
186 CREATE TABLE `tt_fav_reports` (
187 `id` int(11) NOT NULL auto_increment, # favorite report id
188 `name` varchar(200) NOT NULL, # favorite report name
189 `user_id` int(11) NOT NULL, # user id favorite report belongs to
190 `client_id` int(11) default NULL, # client id (if selected)
191 `cf_1_option_id` int(11) default NULL, # custom field 1 option id (if selected)
192 `project_id` int(11) default NULL, # project id (if selected)
193 `task_id` int(11) default NULL, # task id (if selected)
194 `billable` tinyint(4) default NULL, # whether to include billable, not billable, or all records
195 `invoice` tinyint(4) default NULL, # whether to include invoiced, not invoiced, or all records
196 `users` text default NULL, # Comma-separated list of user ids. Nothing here means "all" users.
197 `period` tinyint(4) default NULL, # selected period type for report
198 `period_start` date default NULL, # period start
199 `period_end` date default NULL, # period end
200 `show_client` tinyint(4) NOT NULL default '0', # whether to show client column
201 `show_invoice` tinyint(4) NOT NULL default '0', # whether to show invoice column
202 `show_project` tinyint(4) NOT NULL default '0', # whether to show project column
203 `show_start` tinyint(4) NOT NULL default '0', # whether to show start field
204 `show_duration` tinyint(4) NOT NULL default '0', # whether to show duration field
205 `show_cost` tinyint(4) NOT NULL default '0', # whether to show cost field
206 `show_task` tinyint(4) NOT NULL default '0', # whether to show task column
207 `show_end` tinyint(4) NOT NULL default '0', # whether to show end field
208 `show_note` tinyint(4) NOT NULL default '0', # whether to show note column
209 `show_custom_field_1` tinyint(4) NOT NULL default '0', # whether to show custom field 1
210 `show_totals_only` tinyint(4) NOT NULL default '0', # whether to show totals only
211 `group_by` varchar(20) default NULL, # group by field
217 # Structure for table tt_cron. It is used to email favorite reports on schedule.
219 CREATE TABLE `tt_cron` (
220 `id` int(11) NOT NULL auto_increment, # entry id
221 `team_id` int(11) NOT NULL, # team id
222 `cron_spec` varchar(255) NOT NULL, # cron specification, "0 1 * * *" for "daily at 01:00"
223 `last` int(11) default NULL, # UNIX timestamp of when job was last run
224 `next` int(11) default NULL, # UNIX timestamp of when to run next job
225 `report_id` int(11) default NULL, # report id from tt_fav_reports, a report to mail on schedule
226 `email` varchar(100) default NULL, # email to send results to
227 `status` tinyint(4) default '1', # entry status
233 # Structure for table tt_clients. A client is an entity for whom work is performed and who may be invoiced.
235 CREATE TABLE `tt_clients` (
236 `id` int(11) NOT NULL AUTO_INCREMENT, # client id
237 `team_id` int(11) NOT NULL, # team id
238 `name` varchar(80) COLLATE utf8_bin NOT NULL, # client name
239 `address` varchar(255) default NULL, # client address
240 `tax` float(6,2) default '0.00', # applicable tax for this client
241 `projects` text default NULL, # comma-separated list of project ids assigned to this client
242 `status` tinyint(4) default '1', # client status
246 # Create an index that guarantees unique active and inactive clients per team.
247 create unique index client_name_idx on tt_clients(team_id, name, status);
251 # Structure for table tt_client_project_binds. This table maps clients to assigned projects.
253 CREATE TABLE `tt_client_project_binds` (
254 `client_id` int(11) NOT NULL, # client id
255 `project_id` int(11) NOT NULL # project id
258 # Indexes for tt_client_project_binds.
259 create index client_idx on tt_client_project_binds(client_id);
260 create index project_idx on tt_client_project_binds(project_id);
264 # Structure for table tt_config. This table is used to store configuration info for users.
265 # For example, last_report_email parameter stores an email for user last report was emailed to.
267 CREATE TABLE `tt_config` (
268 `user_id` int(11) NOT NULL, # user id
269 `param_name` varchar(32) NOT NULL, # parameter name
270 `param_value` varchar(80) default NULL # parameter value
273 # Create an index that guarantees unique parameter names per user.
274 create unique index param_idx on tt_config(user_id, param_name);
277 # Below are the tables used by CustomFields plugin.
280 # Structure for table tt_custom_fields. This table contains definitions of custom fields.
282 CREATE TABLE `tt_custom_fields` (
283 `id` int(11) NOT NULL auto_increment, # custom field id
284 `team_id` int(11) NOT NULL, # team id
285 `type` tinyint(4) NOT NULL default '0', # custom field type (text or dropdown)
286 `label` varchar(32) NOT NULL default '', # custom field label
287 `required` tinyint(4) default '0', # whether this custom field is mandatory for time records
288 `status` tinyint(4) default '1', # custom field status
294 # Structure for table tt_custom_field_options. This table defines options for dropdown custom fields.
296 CREATE TABLE `tt_custom_field_options` (
297 `id` int(11) NOT NULL auto_increment, # option id
298 `field_id` int(11) NOT NULL, # custom field id
299 `value` varchar(32) NOT NULL default '', # option value
305 # Structure for table tt_custom_field_log.
306 # This table supplements tt_log and contains custom field values for records.
308 CREATE TABLE `tt_custom_field_log` (
309 `id` bigint NOT NULL auto_increment, # cutom field log id
310 `log_id` bigint NOT NULL, # id of a record in tt_log this record corresponds to
311 `field_id` int(11) NOT NULL, # custom field id
312 `option_id` int(11) default NULL, # Option id. Used for dropdown custom fields.
313 `value` varchar(255) default NULL, # Text value. Used for text custom fields.
314 `status` tinyint(4) default '1', # custom field log entry status
320 # Structure for table tt_expense_items.
321 # This table lists expense items.
323 CREATE TABLE `tt_expense_items` (
324 `id` bigint NOT NULL auto_increment, # expense item id
325 `date` date NOT NULL, # date the record is for
326 `user_id` int(11) NOT NULL, # user id the expense item is reported by
327 `client_id` int(11) default NULL, # client id
328 `project_id` int(11) default NULL, # project id
329 `name` varchar(255) NOT NULL, # expense item name (what is an expense for)
330 `cost` decimal(10,2) default '0.00', # item cost (including taxes, etc.)
331 `invoice_id` int(11) default NULL, # invoice id
332 `status` tinyint(4) default '1', # item status
336 # Create indexes on tt_expense_items for performance.
337 create index date_idx on tt_expense_items(date);
338 create index user_idx on tt_expense_items(user_id);
339 create index client_idx on tt_expense_items(client_id);
340 create index project_idx on tt_expense_items(project_id);
341 create index invoice_idx on tt_expense_items(invoice_id);
345 # Structure for table tt_monthly_quotas.
346 # This table keeps monthly work hour quotas for teams.
348 CREATE TABLE `tt_monthly_quotas` (
349 `team_id` int(11) NOT NULL, # team id
350 `year` smallint(5) UNSIGNED NOT NULL, # quota year
351 `month` tinyint(3) UNSIGNED NOT NULL, # quota month
352 `quota` smallint(5) UNSIGNED NOT NULL, # number of work hours in specified month and year
353 PRIMARY KEY (`team_id`,`year`,`month`)
356 ALTER TABLE `tt_monthly_quotas`
357 ADD CONSTRAINT `FK_TT_TEAM_CONSTRAING` FOREIGN KEY (`team_id`) REFERENCES `tt_teams` (`id`) ON DELETE CASCADE ON UPDATE CASCADE;