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 `name` varchar(80) default NULL, # team name
18 `currency` varchar(7) default NULL, # team currency symbol
19 `decimal_mark` char(1) NOT NULL default '.', # separator in decimals
20 `lang` varchar(10) NOT NULL default 'en', # language
21 `date_format` varchar(20) NOT NULL default '%Y-%m-%d', # date format
22 `time_format` varchar(20) NOT NULL default '%H:%M', # time format
23 `week_start` smallint(2) NOT NULL default 0, # Week start day, 0 == Sunday.
24 `tracking_mode` smallint(2) NOT NULL default 1, # tracking mode ("time", "projects" or "projects and tasks")
25 `project_required` smallint(2) NOT NULL default 0, # whether a project selection is required or optional
26 `task_required` smallint(2) NOT NULL default 0, # whether a task selection is required or optional
27 `record_type` smallint(2) NOT NULL default 0, # time record type ("start and finish", "duration", or both)
28 `bcc_email` varchar(100) default NULL, # bcc email to copy all reports to
29 `plugins` varchar(255) default NULL, # a list of enabled plugins for team
30 `lock_spec` varchar(255) default NULL, # Cron specification for record locking,
31 # for example: "0 10 * * 1" for "weekly on Mon at 10:00".
32 `workday_minutes` smallint(4) default 480, # number of work minutes in a regular working day
33 `custom_logo` tinyint(4) default 0, # whether to use a custom logo or not
34 `config` text default NULL, # miscellaneous team configuration settings
35 `created` datetime default NULL, # creation timestamp
36 `created_ip` varchar(45) default NULL, # creator ip
37 `created_by` int(11) default NULL, # creator user_id
38 `modified` datetime default NULL, # modification timestamp
39 `modified_ip` varchar(45) default NULL, # modifier ip
40 `modified_by` int(11) default NULL, # modifier user_id
41 `status` tinyint(4) default 1, # team status
47 # Structure for table tt_roles. This table stores customized team roles.
49 CREATE TABLE `tt_roles` (
50 `id` int(11) NOT NULL auto_increment, # Role id. Identifies roles for all groups on the server.
51 `team_id` int(11) NOT NULL, # Team id the role is defined for.
52 `name` varchar(80) default NULL, # Role name - custom role name. In case we are editing a
53 # predefined role (USER, etc.), we can rename the role here.
54 `description` varchar(255) default NULL, # Role description.
55 `rank` int(11) default 0, # Role rank, an integer value between 0-324. Predefined role ranks:
56 # USER - 4, CLIENT - 16, COMANAGER - 68, MANAGER - 324.
57 # Rank is used to determine what "lesser roles" are in each group
58 # for sutuations such as "manage_users".
59 # It also identifies a role within a team (by its "rank").
60 # Value of rank is to be used in role field in tt_users table,
61 # just like standard roles now.
62 `rights` text default NULL, # Comma-separated list of rights assigned to a role.
63 # NULL here for predefined roles (4, 16, 68, 324 - manager)
64 # means a hard-coded set of default access rights.
65 `status` tinyint(4) default 1, # Role status.
69 # Create an index that guarantees unique active and inactive role ranks in each group.
70 create unique index role_idx on tt_roles(team_id, rank, status);
72 # Insert site-wide roles - site administrator and top manager.
73 INSERT INTO `tt_roles` (`team_id`, `name`, `rank`, `rights`) VALUES (0, 'Site administrator', 1024, 'administer_site');
74 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_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');
78 # Structure for table tt_users. This table is used to store user properties.
80 CREATE TABLE `tt_users` (
81 `id` int(11) NOT NULL auto_increment, # user id
82 `login` varchar(50) COLLATE utf8_bin NOT NULL, # user login
83 `password` varchar(50) default NULL, # password hash
84 `name` varchar(100) default NULL, # user name
85 `team_id` int(11) NOT NULL, # team id
86 `role_id` int(11) default NULL, # role id
87 `client_id` int(11) default NULL, # client id for "client" user role
88 `rate` float(6,2) NOT NULL default '0.00', # default hourly rate
89 `email` varchar(100) default NULL, # user email
90 `created` datetime default NULL, # creation timestamp
91 `created_ip` varchar(45) default NULL, # creator ip
92 `created_by` int(11) default NULL, # creator user_id (null for self)
93 `modified` datetime default NULL, # modification timestamp
94 `modified_ip` varchar(45) default NULL, # modifier ip
95 `modified_by` int(11) default NULL, # modifier user_id
96 `accessed` datetime default NULL, # last access timestamp
97 `accessed_ip` varchar(45) default NULL, # last access ip
98 `status` tinyint(4) default 1, # user status
102 # Create an index that guarantees unique active and inactive logins.
103 create unique index login_idx on tt_users(login, status);
105 # Create admin account with password 'secret'. Admin is a superuser, who can create teams.
106 DELETE from `tt_users` WHERE login = 'admin';
107 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));
111 # Structure for table tt_projects.
113 CREATE TABLE `tt_projects` (
114 `id` int(11) NOT NULL auto_increment, # project id
115 `team_id` int(11) NOT NULL, # team id
116 `name` varchar(80) COLLATE utf8_bin NOT NULL, # project name
117 `description` varchar(255) default NULL, # project description
118 `tasks` text default NULL, # comma-separated list of task ids associated with this project
119 `status` tinyint(4) default 1, # project status
123 # Create an index that guarantees unique active and inactive projects per team.
124 create unique index project_idx on tt_projects(team_id, name, status);
128 # Structure for table tt_tasks.
130 CREATE TABLE `tt_tasks` (
131 `id` int(11) NOT NULL auto_increment, # task id
132 `team_id` int(11) NOT NULL, # team id
133 `name` varchar(80) COLLATE utf8_bin NOT NULL, # task name
134 `description` varchar(255) default NULL, # task description
135 `status` tinyint(4) default 1, # task status
139 # Create an index that guarantees unique active and inactive tasks per team.
140 create unique index task_idx on tt_tasks(team_id, name, status);
144 # Structure for table tt_user_project_binds. This table maps users to assigned projects.
146 CREATE TABLE `tt_user_project_binds` (
147 `id` int(11) NOT NULL auto_increment, # bind id
148 `user_id` int(11) NOT NULL, # user id
149 `project_id` int(11) NOT NULL, # project id
150 `rate` float(6,2) default '0.00', # rate for this user when working on this project
151 `status` tinyint(4) default 1, # bind status
155 # Create an index that guarantees unique user to project binds.
156 create unique index bind_idx on tt_user_project_binds(user_id, project_id);
160 # Structure for table tt_project_task_binds. This table maps projects to assigned tasks.
162 CREATE TABLE `tt_project_task_binds` (
163 `project_id` int(11) NOT NULL, # project id
164 `task_id` int(11) NOT NULL # task id
167 # Indexes for tt_project_task_binds.
168 create index project_idx on tt_project_task_binds(project_id);
169 create index task_idx on tt_project_task_binds(task_id);
173 # Structure for table tt_log. This is the table where time entries for users are stored.
174 # If you use custom fields, additional info for each record may exist in tt_custom_field_log.
176 CREATE TABLE `tt_log` (
177 `id` bigint NOT NULL auto_increment, # time record id
178 `user_id` int(11) NOT NULL, # user id
179 `date` date NOT NULL, # date the record is for
180 `start` time default NULL, # record start time (for example, 09:00)
181 `duration` time default NULL, # record duration (for example, 1 hour)
182 `client_id` int(11) default NULL, # client id
183 `project_id` int(11) default NULL, # project id
184 `task_id` int(11) default NULL, # task id
185 `invoice_id` int(11) default NULL, # invoice id
186 `comment` text, # user provided comment for time record
187 `billable` tinyint(4) default 0, # whether the record is billable or not
188 `paid` tinyint(4) default 0, # whether the record is paid
189 `created` datetime default NULL, # creation timestamp
190 `created_ip` varchar(45) default NULL, # creator ip
191 `created_by` int(11) default NULL, # creator user_id
192 `modified` datetime default NULL, # modification timestamp
193 `modified_ip` varchar(45) default NULL, # modifier ip
194 `modified_by` int(11) default NULL, # modifier user_id
195 `status` tinyint(4) default 1, # time record status
199 # Create indexes on tt_log for performance.
200 create index date_idx on tt_log(date);
201 create index user_idx on tt_log(user_id);
202 create index client_idx on tt_log(client_id);
203 create index invoice_idx on tt_log(invoice_id);
204 create index project_idx on tt_log(project_id);
205 create index task_idx on tt_log(task_id);
209 # Structure for table tt_invoices. Invoices are issued to clients for billable work.
211 CREATE TABLE `tt_invoices` (
212 `id` int(11) NOT NULL auto_increment, # invoice id
213 `team_id` int(11) NOT NULL, # team id
214 `name` varchar(80) COLLATE utf8_bin NOT NULL, # invoice name
215 `date` date NOT NULL, # invoice date
216 `client_id` int(11) NOT NULL, # client id
217 `status` tinyint(4) default 1, # invoice status
221 # Create an index that guarantees unique invoice names per team.
222 create unique index name_idx on tt_invoices(team_id, name, status);
226 # Structure for table tt_tmp_refs. Used for reset password mechanism.
228 CREATE TABLE `tt_tmp_refs` (
229 `timestamp` timestamp default CURRENT_TIMESTAMP, # creation timestamp
230 `ref` char(32) NOT NULL default '', # unique reference for user, used in urls
231 `user_id` int(11) NOT NULL # user id
236 # Structure for table tt_fav_reports. Favorite reports are pre-configured report configurations.
238 CREATE TABLE `tt_fav_reports` (
239 `id` int(11) NOT NULL auto_increment, # favorite report id
240 `name` varchar(200) NOT NULL, # favorite report name
241 `user_id` int(11) NOT NULL, # user id favorite report belongs to
242 `report_spec` text default NULL, # future replacement field for all report settings
243 `client_id` int(11) default NULL, # client id (if selected)
244 `cf_1_option_id` int(11) default NULL, # custom field 1 option id (if selected)
245 `project_id` int(11) default NULL, # project id (if selected)
246 `task_id` int(11) default NULL, # task id (if selected)
247 `billable` tinyint(4) default NULL, # whether to include billable, not billable, or all records
248 `invoice` tinyint(4) default NULL, # whether to include invoiced, not invoiced, or all records
249 `paid_status` tinyint(4) default NULL, # whether to include paid, not paid, or all records
250 `users` text default NULL, # Comma-separated list of user ids. Nothing here means "all" users.
251 `period` tinyint(4) default NULL, # selected period type for report
252 `period_start` date default NULL, # period start
253 `period_end` date default NULL, # period end
254 `show_client` tinyint(4) NOT NULL default 0, # whether to show client column
255 `show_invoice` tinyint(4) NOT NULL default 0, # whether to show invoice column
256 `show_paid` tinyint(4) NOT NULL default 0, # whether to show paid column
257 `show_ip` tinyint(4) NOT NULL default 0, # whether to show ip column
258 `show_project` tinyint(4) NOT NULL default 0, # whether to show project column
259 `show_start` tinyint(4) NOT NULL default 0, # whether to show start field
260 `show_duration` tinyint(4) NOT NULL default 0, # whether to show duration field
261 `show_cost` tinyint(4) NOT NULL default 0, # whether to show cost field
262 `show_task` tinyint(4) NOT NULL default 0, # whether to show task column
263 `show_end` tinyint(4) NOT NULL default 0, # whether to show end field
264 `show_note` tinyint(4) NOT NULL default 0, # whether to show note column
265 `show_custom_field_1` tinyint(4) NOT NULL default 0, # whether to show custom field 1
266 `show_totals_only` tinyint(4) NOT NULL default 0, # whether to show totals only
267 `group_by` varchar(20) default NULL, # group by field
268 `status` tinyint(4) default 1, # favorite report status
274 # Structure for table tt_cron. It is used to email favorite reports on schedule.
276 CREATE TABLE `tt_cron` (
277 `id` int(11) NOT NULL auto_increment, # entry id
278 `team_id` int(11) NOT NULL, # team id
279 `cron_spec` varchar(255) NOT NULL, # cron specification, "0 1 * * *" for "daily at 01:00"
280 `last` int(11) default NULL, # UNIX timestamp of when job was last run
281 `next` int(11) default NULL, # UNIX timestamp of when to run next job
282 `report_id` int(11) default NULL, # report id from tt_fav_reports, a report to mail on schedule
283 `email` varchar(100) default NULL, # email to send results to
284 `cc` varchar(100) default NULL, # cc email to send results to
285 `subject` varchar(100) default NULL, # email subject
286 `report_condition` varchar(255) default NULL, # report condition, "count > 0" for sending not empty reports
287 `status` tinyint(4) default 1, # entry status
293 # Structure for table tt_clients. A client is an entity for whom work is performed and who may be invoiced.
295 CREATE TABLE `tt_clients` (
296 `id` int(11) NOT NULL AUTO_INCREMENT, # client id
297 `team_id` int(11) NOT NULL, # team id
298 `name` varchar(80) COLLATE utf8_bin NOT NULL, # client name
299 `address` varchar(255) default NULL, # client address
300 `tax` float(6,2) default '0.00', # applicable tax for this client
301 `projects` text default NULL, # comma-separated list of project ids assigned to this client
302 `status` tinyint(4) default 1, # client status
306 # Create an index that guarantees unique active and inactive clients per team.
307 create unique index client_name_idx on tt_clients(team_id, name, status);
311 # Structure for table tt_client_project_binds. This table maps clients to assigned projects.
313 CREATE TABLE `tt_client_project_binds` (
314 `client_id` int(11) NOT NULL, # client id
315 `project_id` int(11) NOT NULL # project id
318 # Indexes for tt_client_project_binds.
319 create index client_idx on tt_client_project_binds(client_id);
320 create index project_idx on tt_client_project_binds(project_id);
324 # Structure for table tt_config. This table is used to store configuration info for users.
325 # For example, last_report_email parameter stores an email for user last report was emailed to.
327 CREATE TABLE `tt_config` (
328 `user_id` int(11) NOT NULL, # user id
329 `param_name` varchar(32) NOT NULL, # parameter name
330 `param_value` varchar(80) default NULL # parameter value
333 # Create an index that guarantees unique parameter names per user.
334 create unique index param_idx on tt_config(user_id, param_name);
337 # Below are the tables used by CustomFields plugin.
340 # Structure for table tt_custom_fields. This table contains definitions of custom fields.
342 CREATE TABLE `tt_custom_fields` (
343 `id` int(11) NOT NULL auto_increment, # custom field id
344 `team_id` int(11) NOT NULL, # team id
345 `type` tinyint(4) NOT NULL default 0, # custom field type (text or dropdown)
346 `label` varchar(32) NOT NULL default '', # custom field label
347 `required` tinyint(4) default 0, # whether this custom field is mandatory for time records
348 `status` tinyint(4) default 1, # custom field status
354 # Structure for table tt_custom_field_options. This table defines options for dropdown custom fields.
356 CREATE TABLE `tt_custom_field_options` (
357 `id` int(11) NOT NULL auto_increment, # option id
358 `field_id` int(11) NOT NULL, # custom field id
359 `value` varchar(32) NOT NULL default '', # option value
365 # Structure for table tt_custom_field_log.
366 # This table supplements tt_log and contains custom field values for records.
368 CREATE TABLE `tt_custom_field_log` (
369 `id` bigint NOT NULL auto_increment, # cutom field log id
370 `log_id` bigint NOT NULL, # id of a record in tt_log this record corresponds to
371 `field_id` int(11) NOT NULL, # custom field id
372 `option_id` int(11) default NULL, # Option id. Used for dropdown custom fields.
373 `value` varchar(255) default NULL, # Text value. Used for text custom fields.
374 `status` tinyint(4) default 1, # custom field log entry status
380 # Structure for table tt_expense_items.
381 # This table lists expense items.
383 CREATE TABLE `tt_expense_items` (
384 `id` bigint NOT NULL auto_increment, # expense item id
385 `date` date NOT NULL, # date the record is for
386 `user_id` int(11) NOT NULL, # user id the expense item is reported by
387 `client_id` int(11) default NULL, # client id
388 `project_id` int(11) default NULL, # project id
389 `name` text NOT NULL, # expense item name (what is an expense for)
390 `cost` decimal(10,2) default '0.00', # item cost (including taxes, etc.)
391 `invoice_id` int(11) default NULL, # invoice id
392 `paid` tinyint(4) default 0, # whether the item is paid
393 `created` datetime default NULL, # creation timestamp
394 `created_ip` varchar(45) default NULL, # creator ip
395 `created_by` int(11) default NULL, # creator user_id
396 `modified` datetime default NULL, # modification timestamp
397 `modified_ip` varchar(45) default NULL, # modifier ip
398 `modified_by` int(11) default NULL, # modifier user_id
399 `status` tinyint(4) default 1, # item status
403 # Create indexes on tt_expense_items for performance.
404 create index date_idx on tt_expense_items(date);
405 create index user_idx on tt_expense_items(user_id);
406 create index client_idx on tt_expense_items(client_id);
407 create index project_idx on tt_expense_items(project_id);
408 create index invoice_idx on tt_expense_items(invoice_id);
412 # Structure for table tt_predefined_expenses.
413 # This table keeps names and costs for predefined expenses.
415 CREATE TABLE `tt_predefined_expenses` (
416 `id` int(11) NOT NULL auto_increment, # predefined expense id
417 `team_id` int(11) NOT NULL, # team id
418 `name` varchar(255) NOT NULL, # predefined expense name, such as mileage
419 `cost` decimal(10,2) default '0.00', # cost for one unit
425 # Structure for table tt_monthly_quotas.
426 # This table keeps monthly work hour quotas for teams.
428 CREATE TABLE `tt_monthly_quotas` (
429 `team_id` int(11) NOT NULL, # team id
430 `year` smallint(5) UNSIGNED NOT NULL, # quota year
431 `month` tinyint(3) UNSIGNED NOT NULL, # quota month
432 `minutes` int(11) default NULL, # quota in minutes in specified month and year
433 PRIMARY KEY (`team_id`,`year`,`month`)
436 ALTER TABLE `tt_monthly_quotas`
437 ADD CONSTRAINT `FK_TT_TEAM_CONSTRAING` FOREIGN KEY (`team_id`) REFERENCES `tt_teams` (`id`) ON DELETE CASCADE ON UPDATE CASCADE;
441 # Structure for table tt_site_config. This table stores configuration data
442 # for Time Tracker site as a whole.
443 # For example, database version, code version, site language, etc.
445 CREATE TABLE `tt_site_config` (
446 `param_name` varchar(32) NOT NULL, # parameter name
447 `param_value` text default NULL, # parameter value
448 `created` datetime default NULL, # creation timestamp
449 `modified` datetime default NULL, # modification timestamp
450 PRIMARY KEY (`param_name`)
453 INSERT INTO `tt_site_config` (`param_name`, `param_value`, `created`) VALUES ('version_db', '1.17.66', now()); # TODO: change when structure changes.