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 `currency` varchar(7) default NULL, # team currency symbol
20 `decimal_mark` char(1) NOT NULL default '.', # separator in decimals
21 `lang` varchar(10) NOT NULL default 'en', # language
22 `date_format` varchar(20) NOT NULL default '%Y-%m-%d', # date format
23 `time_format` varchar(20) NOT NULL default '%H:%M', # time format
24 `week_start` smallint(2) NOT NULL DEFAULT '0', # Week start day, 0 == Sunday.
25 `tracking_mode` smallint(2) NOT NULL DEFAULT '1', # tracking mode ("time", "projects" or "projects and tasks")
26 `project_required` smallint(2) NOT NULL DEFAULT '0', # whether a project selection is required or optional
27 `task_required` smallint(2) NOT NULL DEFAULT '0', # whether a task selection is required or optional
28 `record_type` smallint(2) NOT NULL DEFAULT '0', # time record type ("start and finish", "duration", or both)
29 `uncompleted_indicators` smallint(2) NOT NULL DEFAULT '0', # whether to show indicators for users with uncompleted time entries
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_hours` decimal(5,2) DEFAULT '8.00', # number of work hours in a regular day
35 `custom_logo` tinyint(4) default '0', # whether to use a custom logo or not
36 `status` tinyint(4) default '1', # team status
42 # Structure for table tt_users. This table is used to store user properties.
44 CREATE TABLE `tt_users` (
45 `id` int(11) NOT NULL auto_increment, # user id
46 `timestamp` timestamp NOT NULL, # modification timestamp
47 `login` varchar(50) COLLATE utf8_bin NOT NULL, # user login
48 `password` varchar(50) default NULL, # password hash
49 `name` varchar(100) default NULL, # user name
50 `team_id` int(11) NOT NULL, # team id
51 `role` int(11) default '4', # user role ("manager", "co-manager", "client", or "user")
52 `client_id` int(11) default NULL, # client id for "client" user role
53 `rate` float(6,2) NOT NULL default '0.00', # default hourly rate
54 `email` varchar(100) default NULL, # user email
55 `status` tinyint(4) default '1', # user status
59 # Create an index that guarantees unique active and inactive logins.
60 create unique index login_idx on tt_users(login, status);
62 # Create admin account with password 'secret'. Admin is a superuser, who can create teams.
63 DELETE from `tt_users` WHERE login = 'admin';
64 INSERT INTO `tt_users` (`login`, `password`, `name`, `team_id`, `role`) VALUES ('admin', md5('secret'), 'Admin', '0', '1024');
68 # Structure for table tt_projects.
70 CREATE TABLE `tt_projects` (
71 `id` int(11) NOT NULL auto_increment, # project id
72 `team_id` int(11) NOT NULL, # team id
73 `name` varchar(80) COLLATE utf8_bin NOT NULL, # project name
74 `description` varchar(255) default NULL, # project description
75 `tasks` text default NULL, # comma-separated list of task ids associated with this project
76 `status` tinyint(4) default '1', # project status
80 # Create an index that guarantees unique active and inactive projects per team.
81 create unique index project_idx on tt_projects(team_id, name, status);
85 # Structure for table tt_tasks.
87 CREATE TABLE `tt_tasks` (
88 `id` int(11) NOT NULL auto_increment, # task id
89 `team_id` int(11) NOT NULL, # team id
90 `name` varchar(80) COLLATE utf8_bin NOT NULL, # task name
91 `description` varchar(255) default NULL, # task description
92 `status` tinyint(4) default '1', # task status
96 # Create an index that guarantees unique active and inactive tasks per team.
97 create unique index task_idx on tt_tasks(team_id, name, status);
101 # Structure for table tt_user_project_binds. This table maps users to assigned projects.
103 CREATE TABLE `tt_user_project_binds` (
104 `id` int(11) NOT NULL auto_increment, # bind id
105 `user_id` int(11) NOT NULL, # user id
106 `project_id` int(11) NOT NULL, # project id
107 `rate` float(6,2) default '0.00', # rate for this user when working on this project
108 `status` tinyint(4) default '1', # bind status
112 # Create an index that guarantees unique user to project binds.
113 create unique index bind_idx on tt_user_project_binds(user_id, project_id);
117 # Structure for table tt_project_task_binds. This table maps projects to assigned tasks.
119 CREATE TABLE `tt_project_task_binds` (
120 `project_id` int(11) NOT NULL, # project id
121 `task_id` int(11) NOT NULL # task id
124 # Indexes for tt_project_task_binds.
125 create index project_idx on tt_project_task_binds(project_id);
126 create index task_idx on tt_project_task_binds(task_id);
130 # Structure for table tt_log. This is the table where time entries for users are stored.
131 # If you use custom fields, additional info for each record may exist in tt_custom_field_log.
133 CREATE TABLE `tt_log` (
134 `id` bigint NOT NULL auto_increment, # time record id
135 `timestamp` timestamp NOT NULL, # modification timestamp
136 `user_id` int(11) NOT NULL, # user id
137 `date` date NOT NULL, # date the record is for
138 `start` time default NULL, # record start time (for example, 09:00)
139 `duration` time default NULL, # record duration (for example, 1 hour)
140 `client_id` int(11) default NULL, # client id
141 `project_id` int(11) default NULL, # project id
142 `task_id` int(11) default NULL, # task id
143 `invoice_id` int(11) default NULL, # invoice id
144 `comment` text, # user provided comment for time record
145 `billable` tinyint(4) default '0', # whether the record is billable or not
146 `paid` tinyint(4) default '0', # whether the record is paid
147 `status` tinyint(4) default '1', # time record status
151 # Create indexes on tt_log for performance.
152 create index date_idx on tt_log(date);
153 create index user_idx on tt_log(user_id);
154 create index client_idx on tt_log(client_id);
155 create index invoice_idx on tt_log(invoice_id);
156 create index project_idx on tt_log(project_id);
157 create index task_idx on tt_log(task_id);
161 # Structure for table tt_invoices. Invoices are issued to clients for billable work.
163 CREATE TABLE `tt_invoices` (
164 `id` int(11) NOT NULL auto_increment, # invoice id
165 `team_id` int(11) NOT NULL, # team id
166 `name` varchar(80) COLLATE utf8_bin NOT NULL, # invoice name
167 `date` date NOT NULL, # invoice date
168 `client_id` int(11) NOT NULL, # client id
169 `status` tinyint(4) default '1', # invoice status
173 # Create an index that guarantees unique invoice names per team.
174 create unique index name_idx on tt_invoices(team_id, name, status);
178 # Structure for table tt_tmp_refs. Used for reset password mechanism.
180 CREATE TABLE `tt_tmp_refs` (
181 `timestamp` timestamp NOT NULL, # creation timestamp
182 `ref` char(32) NOT NULL default '', # unique reference for user, used in urls
183 `user_id` int(11) NOT NULL # user id
188 # Structure for table tt_fav_reports. Favorite reports are pre-configured report configurations.
190 CREATE TABLE `tt_fav_reports` (
191 `id` int(11) NOT NULL auto_increment, # favorite report id
192 `name` varchar(200) NOT NULL, # favorite report name
193 `user_id` int(11) NOT NULL, # user id favorite report belongs to
194 `report_spec` text default NULL, # future replacement field for all report settings
195 `client_id` int(11) default NULL, # client id (if selected)
196 `cf_1_option_id` int(11) default NULL, # custom field 1 option id (if selected)
197 `project_id` int(11) default NULL, # project id (if selected)
198 `task_id` int(11) default NULL, # task id (if selected)
199 `billable` tinyint(4) default NULL, # whether to include billable, not billable, or all records
200 `invoice` tinyint(4) default NULL, # whether to include invoiced, not invoiced, or all records
201 `paid_status` tinyint(4) default NULL, # whether to include paid, not paid, or all records
202 `users` text default NULL, # Comma-separated list of user ids. Nothing here means "all" users.
203 `period` tinyint(4) default NULL, # selected period type for report
204 `period_start` date default NULL, # period start
205 `period_end` date default NULL, # period end
206 `show_client` tinyint(4) NOT NULL default '0', # whether to show client column
207 `show_invoice` tinyint(4) NOT NULL default '0', # whether to show invoice column
208 `show_paid` tinyint(4) NOT NULL default '0', # whether to show paid column
209 `show_project` tinyint(4) NOT NULL default '0', # whether to show project column
210 `show_start` tinyint(4) NOT NULL default '0', # whether to show start field
211 `show_duration` tinyint(4) NOT NULL default '0', # whether to show duration field
212 `show_cost` tinyint(4) NOT NULL default '0', # whether to show cost field
213 `show_task` tinyint(4) NOT NULL default '0', # whether to show task column
214 `show_end` tinyint(4) NOT NULL default '0', # whether to show end field
215 `show_note` tinyint(4) NOT NULL default '0', # whether to show note column
216 `show_custom_field_1` tinyint(4) NOT NULL default '0', # whether to show custom field 1
217 `show_totals_only` tinyint(4) NOT NULL default '0', # whether to show totals only
218 `group_by` varchar(20) default NULL, # group by field
219 `status` tinyint(4) default '1', # favorite report status
225 # Structure for table tt_cron. It is used to email favorite reports on schedule.
227 CREATE TABLE `tt_cron` (
228 `id` int(11) NOT NULL auto_increment, # entry id
229 `team_id` int(11) NOT NULL, # team id
230 `cron_spec` varchar(255) NOT NULL, # cron specification, "0 1 * * *" for "daily at 01:00"
231 `last` int(11) default NULL, # UNIX timestamp of when job was last run
232 `next` int(11) default NULL, # UNIX timestamp of when to run next job
233 `report_id` int(11) default NULL, # report id from tt_fav_reports, a report to mail on schedule
234 `email` varchar(100) default NULL, # email to send results to
235 `cc` varchar(100) default NULL, # cc email to send results to
236 `subject` varchar(100) default NULL, # email subject
237 `report_condition` varchar(255) default NULL, # report condition, "count > 0" for sending not empty reports
238 `status` tinyint(4) default '1', # entry status
244 # Structure for table tt_clients. A client is an entity for whom work is performed and who may be invoiced.
246 CREATE TABLE `tt_clients` (
247 `id` int(11) NOT NULL AUTO_INCREMENT, # client id
248 `team_id` int(11) NOT NULL, # team id
249 `name` varchar(80) COLLATE utf8_bin NOT NULL, # client name
250 `address` varchar(255) default NULL, # client address
251 `tax` float(6,2) default '0.00', # applicable tax for this client
252 `projects` text default NULL, # comma-separated list of project ids assigned to this client
253 `status` tinyint(4) default '1', # client status
257 # Create an index that guarantees unique active and inactive clients per team.
258 create unique index client_name_idx on tt_clients(team_id, name, status);
262 # Structure for table tt_client_project_binds. This table maps clients to assigned projects.
264 CREATE TABLE `tt_client_project_binds` (
265 `client_id` int(11) NOT NULL, # client id
266 `project_id` int(11) NOT NULL # project id
269 # Indexes for tt_client_project_binds.
270 create index client_idx on tt_client_project_binds(client_id);
271 create index project_idx on tt_client_project_binds(project_id);
275 # Structure for table tt_config. This table is used to store configuration info for users.
276 # For example, last_report_email parameter stores an email for user last report was emailed to.
278 CREATE TABLE `tt_config` (
279 `user_id` int(11) NOT NULL, # user id
280 `param_name` varchar(32) NOT NULL, # parameter name
281 `param_value` varchar(80) default NULL # parameter value
284 # Create an index that guarantees unique parameter names per user.
285 create unique index param_idx on tt_config(user_id, param_name);
288 # Below are the tables used by CustomFields plugin.
291 # Structure for table tt_custom_fields. This table contains definitions of custom fields.
293 CREATE TABLE `tt_custom_fields` (
294 `id` int(11) NOT NULL auto_increment, # custom field id
295 `team_id` int(11) NOT NULL, # team id
296 `type` tinyint(4) NOT NULL default '0', # custom field type (text or dropdown)
297 `label` varchar(32) NOT NULL default '', # custom field label
298 `required` tinyint(4) default '0', # whether this custom field is mandatory for time records
299 `status` tinyint(4) default '1', # custom field status
305 # Structure for table tt_custom_field_options. This table defines options for dropdown custom fields.
307 CREATE TABLE `tt_custom_field_options` (
308 `id` int(11) NOT NULL auto_increment, # option id
309 `field_id` int(11) NOT NULL, # custom field id
310 `value` varchar(32) NOT NULL default '', # option value
316 # Structure for table tt_custom_field_log.
317 # This table supplements tt_log and contains custom field values for records.
319 CREATE TABLE `tt_custom_field_log` (
320 `id` bigint NOT NULL auto_increment, # cutom field log id
321 `log_id` bigint NOT NULL, # id of a record in tt_log this record corresponds to
322 `field_id` int(11) NOT NULL, # custom field id
323 `option_id` int(11) default NULL, # Option id. Used for dropdown custom fields.
324 `value` varchar(255) default NULL, # Text value. Used for text custom fields.
325 `status` tinyint(4) default '1', # custom field log entry status
331 # Structure for table tt_expense_items.
332 # This table lists expense items.
334 CREATE TABLE `tt_expense_items` (
335 `id` bigint NOT NULL auto_increment, # expense item id
336 `date` date NOT NULL, # date the record is for
337 `user_id` int(11) NOT NULL, # user id the expense item is reported by
338 `client_id` int(11) default NULL, # client id
339 `project_id` int(11) default NULL, # project id
340 `name` text NOT NULL, # expense item name (what is an expense for)
341 `cost` decimal(10,2) default '0.00', # item cost (including taxes, etc.)
342 `invoice_id` int(11) default NULL, # invoice id
343 `paid` tinyint(4) default '0', # whether the item is paid
344 `status` tinyint(4) default '1', # item status
348 # Create indexes on tt_expense_items for performance.
349 create index date_idx on tt_expense_items(date);
350 create index user_idx on tt_expense_items(user_id);
351 create index client_idx on tt_expense_items(client_id);
352 create index project_idx on tt_expense_items(project_id);
353 create index invoice_idx on tt_expense_items(invoice_id);
357 # Structure for table tt_predefined_expenses.
358 # This table keeps names and costs for predefined expenses.
360 CREATE TABLE `tt_predefined_expenses` (
361 `id` int(11) NOT NULL auto_increment, # predefined expense id
362 `team_id` int(11) NOT NULL, # team id
363 `name` varchar(255) NOT NULL, # predefined expense name, such as mileage
364 `cost` decimal(10,2) default '0.00', # cost for one unit
370 # Structure for table tt_monthly_quotas.
371 # This table keeps monthly work hour quotas for teams.
373 CREATE TABLE `tt_monthly_quotas` (
374 `team_id` int(11) NOT NULL, # team id
375 `year` smallint(5) UNSIGNED NOT NULL, # quota year
376 `month` tinyint(3) UNSIGNED NOT NULL, # quota month
377 `quota` decimal(5,2) NOT NULL, # number of work hours in specified month and year
378 PRIMARY KEY (`team_id`,`year`,`month`)
381 ALTER TABLE `tt_monthly_quotas`
382 ADD CONSTRAINT `FK_TT_TEAM_CONSTRAING` FOREIGN KEY (`team_id`) REFERENCES `tt_teams` (`id`) ON DELETE CASCADE ON UPDATE CASCADE;