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 group members such as language, week start day, etc.
15 CREATE TABLE `tt_teams` (
16 `id` int(11) NOT NULL auto_increment, # group id
17 `parent_id` int(11) default NULL, # parent group id
18 `org_id` int(11) default NULL, # organization id (id of top group)
19 `name` varchar(80) default NULL, # group name
20 `currency` varchar(7) default NULL, # 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 ("time", "projects" or "projects and tasks")
27 `project_required` smallint(2) NOT NULL default 0, # whether a project selection is required or optional
28 `task_required` smallint(2) NOT NULL default 0, # whether a task selection is required or optional
29 `record_type` smallint(2) NOT NULL default 0, # time record type ("start and finish", "duration", or both)
30 `bcc_email` varchar(100) default NULL, # bcc email to copy all reports to
31 `plugins` varchar(255) default NULL, # a list of enabled plugins for team
32 `lock_spec` varchar(255) default NULL, # Cron specification for record locking,
33 # for example: "0 10 * * 1" for "weekly on Mon at 10:00".
34 `workday_minutes` smallint(4) default 480, # number of work minutes in a regular working day
35 `custom_logo` tinyint(4) default 0, # whether to use a custom logo or not
36 `config` text default NULL, # miscellaneous group configuration settings
37 `created` datetime default NULL, # creation timestamp
38 `created_ip` varchar(45) default NULL, # creator ip
39 `created_by` int(11) default NULL, # creator user_id
40 `modified` datetime default NULL, # modification timestamp
41 `modified_ip` varchar(45) default NULL, # modifier ip
42 `modified_by` int(11) default NULL, # modifier user_id
43 `status` tinyint(4) default 1, # group status
49 # Structure for table tt_roles. This table stores customized team roles.
51 CREATE TABLE `tt_roles` (
52 `id` int(11) NOT NULL auto_increment, # Role id. Identifies roles for all groups on the server.
53 `team_id` int(11) NOT NULL, # Team id the role is defined for.
54 `name` varchar(80) default NULL, # Role name - custom role name. In case we are editing a
55 # predefined role (USER, etc.), we can rename the role here.
56 `description` varchar(255) default NULL, # Role description.
57 `rank` int(11) default 0, # Role rank, an integer value between 0-324. Predefined role ranks:
58 # USER - 4, CLIENT - 16, COMANAGER - 68, MANAGER - 324.
59 # Rank is used to determine what "lesser roles" are in each group
60 # for sutuations such as "manage_users".
61 # It also identifies a role within a team (by its "rank").
62 # Value of rank is to be used in role field in tt_users table,
63 # just like standard roles now.
64 `rights` text default NULL, # Comma-separated list of rights assigned to a role.
65 # NULL here for predefined roles (4, 16, 68, 324 - manager)
66 # means a hard-coded set of default access rights.
67 `status` tinyint(4) default 1, # Role status.
71 # Create an index that guarantees unique active and inactive role ranks in each group.
72 create unique index role_idx on tt_roles(team_id, rank, status);
74 # Insert site-wide roles - site administrator and top manager.
75 INSERT INTO `tt_roles` (`team_id`, `name`, `rank`, `rights`) VALUES (0, 'Site administrator', 1024, 'administer_site');
76 INSERT INTO `tt_roles` (`team_id`, `name`, `rank`, `rights`) VALUES (0, 'Top manager', 512, 'track_own_time,track_own_expenses,view_own_reports,view_own_charts,view_own_invoices,manage_own_settings,view_users,track_time,track_expenses,view_reports,view_charts,override_punch_mode,override_own_punch_mode,override_date_lock,override_own_date_lock,swap_roles,approve_timesheets,manage_own_account,manage_users,manage_projects,manage_tasks,manage_custom_fields,manage_clients,manage_invoices,manage_features,manage_basic_settings,manage_advanced_settings,manage_roles,export_data,manage_subgroups');
80 # Structure for table tt_users. This table is used to store user properties.
82 CREATE TABLE `tt_users` (
83 `id` int(11) NOT NULL auto_increment, # user id
84 `login` varchar(50) COLLATE utf8_bin NOT NULL, # user login
85 `password` varchar(50) default NULL, # password hash
86 `name` varchar(100) default NULL, # user name
87 `team_id` int(11) NOT NULL, # team id
88 `role_id` int(11) default NULL, # role id
89 `client_id` int(11) default NULL, # client id for "client" user role
90 `rate` float(6,2) NOT NULL default '0.00', # default hourly rate
91 `email` varchar(100) default NULL, # user email
92 `created` datetime default NULL, # creation timestamp
93 `created_ip` varchar(45) default NULL, # creator ip
94 `created_by` int(11) default NULL, # creator user_id (null for self)
95 `modified` datetime default NULL, # modification timestamp
96 `modified_ip` varchar(45) default NULL, # modifier ip
97 `modified_by` int(11) default NULL, # modifier user_id
98 `accessed` datetime default NULL, # last access timestamp
99 `accessed_ip` varchar(45) default NULL, # last access ip
100 `status` tinyint(4) default 1, # user status
104 # Create an index that guarantees unique active and inactive logins.
105 create unique index login_idx on tt_users(login, status);
107 # Create admin account with password 'secret'. Admin is a superuser, who can create teams.
108 DELETE from `tt_users` WHERE login = 'admin';
109 INSERT INTO `tt_users` (`login`, `password`, `name`, `team_id`, `role_id`) VALUES ('admin', md5('secret'), 'Admin', '0', (select id from tt_roles where rank = 1024));
113 # Structure for table tt_projects.
115 CREATE TABLE `tt_projects` (
116 `id` int(11) NOT NULL auto_increment, # project id
117 `team_id` int(11) NOT NULL, # team id
118 `name` varchar(80) COLLATE utf8_bin NOT NULL, # project name
119 `description` varchar(255) default NULL, # project description
120 `tasks` text default NULL, # comma-separated list of task ids associated with this project
121 `status` tinyint(4) default 1, # project status
125 # Create an index that guarantees unique active and inactive projects per team.
126 create unique index project_idx on tt_projects(team_id, name, status);
130 # Structure for table tt_tasks.
132 CREATE TABLE `tt_tasks` (
133 `id` int(11) NOT NULL auto_increment, # task id
134 `team_id` int(11) NOT NULL, # team id
135 `name` varchar(80) COLLATE utf8_bin NOT NULL, # task name
136 `description` varchar(255) default NULL, # task description
137 `status` tinyint(4) default 1, # task status
141 # Create an index that guarantees unique active and inactive tasks per team.
142 create unique index task_idx on tt_tasks(team_id, name, status);
146 # Structure for table tt_user_project_binds. This table maps users to assigned projects.
148 CREATE TABLE `tt_user_project_binds` (
149 `id` int(11) NOT NULL auto_increment, # bind id
150 `user_id` int(11) NOT NULL, # user id
151 `project_id` int(11) NOT NULL, # project id
152 `rate` float(6,2) default '0.00', # rate for this user when working on this project
153 `status` tinyint(4) default 1, # bind status
157 # Create an index that guarantees unique user to project binds.
158 create unique index bind_idx on tt_user_project_binds(user_id, project_id);
162 # Structure for table tt_project_task_binds. This table maps projects to assigned tasks.
164 CREATE TABLE `tt_project_task_binds` (
165 `project_id` int(11) NOT NULL, # project id
166 `task_id` int(11) NOT NULL # task id
169 # Indexes for tt_project_task_binds.
170 create index project_idx on tt_project_task_binds(project_id);
171 create index task_idx on tt_project_task_binds(task_id);
175 # Structure for table tt_log. This is the table where time entries for users are stored.
176 # If you use custom fields, additional info for each record may exist in tt_custom_field_log.
178 CREATE TABLE `tt_log` (
179 `id` bigint NOT NULL auto_increment, # time record id
180 `user_id` int(11) NOT NULL, # user id
181 `date` date NOT NULL, # date the record is for
182 `start` time default NULL, # record start time (for example, 09:00)
183 `duration` time default NULL, # record duration (for example, 1 hour)
184 `client_id` int(11) default NULL, # client id
185 `project_id` int(11) default NULL, # project id
186 `task_id` int(11) default NULL, # task id
187 `invoice_id` int(11) default NULL, # invoice id
188 `comment` text, # user provided comment for time record
189 `billable` tinyint(4) default 0, # whether the record is billable or not
190 `paid` tinyint(4) default 0, # whether the record is paid
191 `created` datetime default NULL, # creation timestamp
192 `created_ip` varchar(45) default NULL, # creator ip
193 `created_by` int(11) default NULL, # creator user_id
194 `modified` datetime default NULL, # modification timestamp
195 `modified_ip` varchar(45) default NULL, # modifier ip
196 `modified_by` int(11) default NULL, # modifier user_id
197 `status` tinyint(4) default 1, # time record status
201 # Create indexes on tt_log for performance.
202 create index date_idx on tt_log(date);
203 create index user_idx on tt_log(user_id);
204 create index client_idx on tt_log(client_id);
205 create index invoice_idx on tt_log(invoice_id);
206 create index project_idx on tt_log(project_id);
207 create index task_idx on tt_log(task_id);
211 # Structure for table tt_invoices. Invoices are issued to clients for billable work.
213 CREATE TABLE `tt_invoices` (
214 `id` int(11) NOT NULL auto_increment, # invoice id
215 `team_id` int(11) NOT NULL, # team id
216 `name` varchar(80) COLLATE utf8_bin NOT NULL, # invoice name
217 `date` date NOT NULL, # invoice date
218 `client_id` int(11) NOT NULL, # client id
219 `status` tinyint(4) default 1, # invoice status
223 # Create an index that guarantees unique invoice names per team.
224 create unique index name_idx on tt_invoices(team_id, name, status);
228 # Structure for table tt_tmp_refs. Used for reset password mechanism.
230 CREATE TABLE `tt_tmp_refs` (
231 `created` datetime default NULL, # creation timestamp
232 `ref` char(32) NOT NULL default '', # unique reference for user, used in urls
233 `user_id` int(11) NOT NULL # user id
238 # Structure for table tt_fav_reports. Favorite reports are pre-configured report configurations.
240 CREATE TABLE `tt_fav_reports` (
241 `id` int(11) NOT NULL auto_increment, # favorite report id
242 `name` varchar(200) NOT NULL, # favorite report name
243 `user_id` int(11) NOT NULL, # user id favorite report belongs to
244 `report_spec` text default NULL, # future replacement field for all report settings
245 `client_id` int(11) default NULL, # client id (if selected)
246 `cf_1_option_id` int(11) default NULL, # custom field 1 option id (if selected)
247 `project_id` int(11) default NULL, # project id (if selected)
248 `task_id` int(11) default NULL, # task id (if selected)
249 `billable` tinyint(4) default NULL, # whether to include billable, not billable, or all records
250 `invoice` tinyint(4) default NULL, # whether to include invoiced, not invoiced, or all records
251 `paid_status` tinyint(4) default NULL, # whether to include paid, not paid, or all records
252 `users` text default NULL, # Comma-separated list of user ids. Nothing here means "all" users.
253 `period` tinyint(4) default NULL, # selected period type for report
254 `period_start` date default NULL, # period start
255 `period_end` date default NULL, # period end
256 `show_client` tinyint(4) NOT NULL default 0, # whether to show client column
257 `show_invoice` tinyint(4) NOT NULL default 0, # whether to show invoice column
258 `show_paid` tinyint(4) NOT NULL default 0, # whether to show paid column
259 `show_ip` tinyint(4) NOT NULL default 0, # whether to show ip column
260 `show_project` tinyint(4) NOT NULL default 0, # whether to show project column
261 `show_start` tinyint(4) NOT NULL default 0, # whether to show start field
262 `show_duration` tinyint(4) NOT NULL default 0, # whether to show duration field
263 `show_cost` tinyint(4) NOT NULL default 0, # whether to show cost field
264 `show_task` tinyint(4) NOT NULL default 0, # whether to show task column
265 `show_end` tinyint(4) NOT NULL default 0, # whether to show end field
266 `show_note` tinyint(4) NOT NULL default 0, # whether to show note column
267 `show_custom_field_1` tinyint(4) NOT NULL default 0, # whether to show custom field 1
268 `show_totals_only` tinyint(4) NOT NULL default 0, # whether to show totals only
269 `group_by` varchar(20) default NULL, # group by field
270 `status` tinyint(4) default 1, # favorite report status
276 # Structure for table tt_cron. It is used to email favorite reports on schedule.
278 CREATE TABLE `tt_cron` (
279 `id` int(11) NOT NULL auto_increment, # entry id
280 `team_id` int(11) NOT NULL, # team id
281 `cron_spec` varchar(255) NOT NULL, # cron specification, "0 1 * * *" for "daily at 01:00"
282 `last` int(11) default NULL, # UNIX timestamp of when job was last run
283 `next` int(11) default NULL, # UNIX timestamp of when to run next job
284 `report_id` int(11) default NULL, # report id from tt_fav_reports, a report to mail on schedule
285 `email` varchar(100) default NULL, # email to send results to
286 `cc` varchar(100) default NULL, # cc email to send results to
287 `subject` varchar(100) default NULL, # email subject
288 `report_condition` varchar(255) default NULL, # report condition, "count > 0" for sending not empty reports
289 `status` tinyint(4) default 1, # entry status
295 # Structure for table tt_clients. A client is an entity for whom work is performed and who may be invoiced.
297 CREATE TABLE `tt_clients` (
298 `id` int(11) NOT NULL AUTO_INCREMENT, # client id
299 `team_id` int(11) NOT NULL, # team id
300 `name` varchar(80) COLLATE utf8_bin NOT NULL, # client name
301 `address` varchar(255) default NULL, # client address
302 `tax` float(6,2) default '0.00', # applicable tax for this client
303 `projects` text default NULL, # comma-separated list of project ids assigned to this client
304 `status` tinyint(4) default 1, # client status
308 # Create an index that guarantees unique active and inactive clients per team.
309 create unique index client_name_idx on tt_clients(team_id, name, status);
313 # Structure for table tt_client_project_binds. This table maps clients to assigned projects.
315 CREATE TABLE `tt_client_project_binds` (
316 `client_id` int(11) NOT NULL, # client id
317 `project_id` int(11) NOT NULL # project id
320 # Indexes for tt_client_project_binds.
321 create index client_idx on tt_client_project_binds(client_id);
322 create index project_idx on tt_client_project_binds(project_id);
326 # Structure for table tt_config. This table is used to store configuration info for users.
327 # For example, last_report_email parameter stores an email for user last report was emailed to.
329 CREATE TABLE `tt_config` (
330 `user_id` int(11) NOT NULL, # user id
331 `param_name` varchar(32) NOT NULL, # parameter name
332 `param_value` varchar(80) default NULL # parameter value
335 # Create an index that guarantees unique parameter names per user.
336 create unique index param_idx on tt_config(user_id, param_name);
339 # Below are the tables used by CustomFields plugin.
342 # Structure for table tt_custom_fields. This table contains definitions of custom fields.
344 CREATE TABLE `tt_custom_fields` (
345 `id` int(11) NOT NULL auto_increment, # custom field id
346 `team_id` int(11) NOT NULL, # team id
347 `type` tinyint(4) NOT NULL default 0, # custom field type (text or dropdown)
348 `label` varchar(32) NOT NULL default '', # custom field label
349 `required` tinyint(4) default 0, # whether this custom field is mandatory for time records
350 `status` tinyint(4) default 1, # custom field status
356 # Structure for table tt_custom_field_options. This table defines options for dropdown custom fields.
358 CREATE TABLE `tt_custom_field_options` (
359 `id` int(11) NOT NULL auto_increment, # option id
360 `field_id` int(11) NOT NULL, # custom field id
361 `value` varchar(32) NOT NULL default '', # option value
367 # Structure for table tt_custom_field_log.
368 # This table supplements tt_log and contains custom field values for records.
370 CREATE TABLE `tt_custom_field_log` (
371 `id` bigint NOT NULL auto_increment, # cutom field log id
372 `log_id` bigint NOT NULL, # id of a record in tt_log this record corresponds to
373 `field_id` int(11) NOT NULL, # custom field id
374 `option_id` int(11) default NULL, # Option id. Used for dropdown custom fields.
375 `value` varchar(255) default NULL, # Text value. Used for text custom fields.
376 `status` tinyint(4) default 1, # custom field log entry status
382 # Structure for table tt_expense_items.
383 # This table lists expense items.
385 CREATE TABLE `tt_expense_items` (
386 `id` bigint NOT NULL auto_increment, # expense item id
387 `date` date NOT NULL, # date the record is for
388 `user_id` int(11) NOT NULL, # user id the expense item is reported by
389 `client_id` int(11) default NULL, # client id
390 `project_id` int(11) default NULL, # project id
391 `name` text NOT NULL, # expense item name (what is an expense for)
392 `cost` decimal(10,2) default '0.00', # item cost (including taxes, etc.)
393 `invoice_id` int(11) default NULL, # invoice id
394 `paid` tinyint(4) default 0, # whether the item is paid
395 `created` datetime default NULL, # creation timestamp
396 `created_ip` varchar(45) default NULL, # creator ip
397 `created_by` int(11) default NULL, # creator user_id
398 `modified` datetime default NULL, # modification timestamp
399 `modified_ip` varchar(45) default NULL, # modifier ip
400 `modified_by` int(11) default NULL, # modifier user_id
401 `status` tinyint(4) default 1, # item status
405 # Create indexes on tt_expense_items for performance.
406 create index date_idx on tt_expense_items(date);
407 create index user_idx on tt_expense_items(user_id);
408 create index client_idx on tt_expense_items(client_id);
409 create index project_idx on tt_expense_items(project_id);
410 create index invoice_idx on tt_expense_items(invoice_id);
414 # Structure for table tt_predefined_expenses.
415 # This table keeps names and costs for predefined expenses.
417 CREATE TABLE `tt_predefined_expenses` (
418 `id` int(11) NOT NULL auto_increment, # predefined expense id
419 `team_id` int(11) NOT NULL, # team id
420 `name` varchar(255) NOT NULL, # predefined expense name, such as mileage
421 `cost` decimal(10,2) default '0.00', # cost for one unit
427 # Structure for table tt_monthly_quotas.
428 # This table keeps monthly work hour quotas for teams.
430 CREATE TABLE `tt_monthly_quotas` (
431 `team_id` int(11) NOT NULL, # team id
432 `year` smallint(5) UNSIGNED NOT NULL, # quota year
433 `month` tinyint(3) UNSIGNED NOT NULL, # quota month
434 `minutes` int(11) default NULL, # quota in minutes in specified month and year
435 PRIMARY KEY (`team_id`,`year`,`month`)
438 ALTER TABLE `tt_monthly_quotas`
439 ADD CONSTRAINT `FK_TT_TEAM_CONSTRAING` FOREIGN KEY (`team_id`) REFERENCES `tt_teams` (`id`) ON DELETE CASCADE ON UPDATE CASCADE;
443 # Structure for table tt_site_config. This table stores configuration data
444 # for Time Tracker site as a whole.
445 # For example, database version, code version, site language, etc.
447 CREATE TABLE `tt_site_config` (
448 `param_name` varchar(32) NOT NULL, # parameter name
449 `param_value` text default NULL, # parameter value
450 `created` datetime default NULL, # creation timestamp
451 `modified` datetime default NULL, # modification timestamp
452 PRIMARY KEY (`param_name`)
455 INSERT INTO `tt_site_config` (`param_name`, `param_value`, `created`) VALUES ('version_db', '1.17.77', now()); # TODO: change when structure changes.