summaryrefslogtreecommitdiff
path: root/db/schema/vendors.ts
blob: d53fb67496fcc6c21298da269c0d988018217b01 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
// db/schema/vendors.ts
import {  pgTable, serial, varchar, text, timestamp, boolean, integer ,pgView} from "drizzle-orm/pg-core";
import { items, materials } from "./items";
import { sql, eq, relations } from "drizzle-orm";
import { users } from "./users";


// vendorTypes 테이블 생성
export const vendorTypes = pgTable("vendor_types", {
  id: serial("id").primaryKey(),
  code: varchar("code", { length: 50 }).notNull().unique(),
  nameKo: varchar("name_ko", { length: 255 }).notNull(),
  nameEn: varchar("name_en", { length: 255 }).notNull(),
  createdAt: timestamp("created_at").defaultNow().notNull(),
  updatedAt: timestamp("updated_at").defaultNow().notNull(),
});


export const vendors = pgTable("vendors", {
  id: serial("id").primaryKey(),
  vendorName: varchar("vendor_name", { length: 255 }).notNull(),
  // 벤더 코드 유니크 아니어도 괜찮은지?
  vendorCode: varchar("vendor_code", { length: 100 }),
  //사업자번호이고, 법인등록번호는 corporateRegistrationNumber
  taxId: varchar("tax_id", { length: 100 }).notNull(),
  address: text("address"),
  addressDetail: text("address_detail"),
  postalCode: varchar("postal_code", { length: 20 }),
  country: varchar("country", { length: 100 }),
  phone: varchar("phone", { length: 50 }),
  email: varchar("email", { length: 255 }),
  website: varchar("website", { length: 255 }),
  status: varchar("status", {
    length: 30,
    enum: [
      "PENDING_REVIEW",   // 가입 신청 중 (초기 신청)
      "IN_REVIEW",        // 심사 중
      "REJECTED",         // 심사 거부됨
      "IN_PQ",            // PQ 진행 중
      "PQ_SUBMITTED",     // PQ 제출
      "PQ_FAILED",        // PQ 실패
      "PQ_APPROVED",      // PQ 통과, 승인됨
      "APPROVED",         // PQ 통과, 승인됨
      "READY_TO_SEND",         // PQ 통과, 승인됨
      "ACTIVE",           // 활성 상태 (실제 거래 중)
      "INACTIVE",         // 비활성 상태 (일시적)
      "BLACKLISTED",      // 거래 금지 상태
    ]
  })
    .notNull()
    .default("PENDING_REVIEW"),
  vendorTypeId: integer("vendor_type_id").references(() => vendorTypes.id),
  representativeName: varchar("representative_name", { length: 255 }),
  representativeBirth: varchar("representative_birth", { length: 20 }),
  representativeEmail: varchar("representative_email", { length: 255 }),
  representativePhone: varchar("representative_phone", { length: 50 }),
  representativeWorkExpirence: boolean("representative_work_expirence").default(false),
  corporateRegistrationNumber: varchar("corporate_registration_number", {
    length: 100,
  }),
  items: text("items"),

  creditAgency: varchar("credit_agency", { length: 50 }),
  creditRating: varchar("credit_rating", { length: 50 }),
  cashFlowRating: varchar("cash_flow_rating", { length: 50 }),

  businessSize: varchar("business_size", { length: 255 }),

  // // PQ 승인시 받을 정보
  // // 그룹사
  // groupCompany: varchar("group_company", { length: 255 }),
  // // 설립일
  // establishmentDate: timestamp("establishment_date"),
  // // Fax 주소
  // faxAddress: varchar("fax_address", { length: 255 }),
  // // 임직원 수
  // employeeCount: varchar("employee_count", { length: 255 }),
  // // 연간 매출액
  // annualSales: text("annual_sales"),
  // // 자산
  // assets: text("assets"),
  // // 생산능력
  // productionCapacity: text("production_capacity"),
  // // 조직도
  // organizationChart: text("organization_chart"),


  createdAt: timestamp("created_at").defaultNow().notNull(),
  updatedAt: timestamp("updated_at").defaultNow().notNull(),

  // VENDOR_GENERAL 테이블은 별도 테이블로 분리함
});

// eVCP 내 연락처로 오라클 측과는 무관...
export const vendorContacts = pgTable("vendor_contacts", {
  id: serial("id").primaryKey(),
  vendorId: integer("vendor_id").notNull().references(() => vendors.id),
  contactName: varchar("contact_name", { length: 255 }).notNull(),
  contactPosition: varchar("contact_position", { length: 100 }),
  contactDepartment: varchar("contact_department", { length: 100 }),
  contactTask: varchar("contact_task", { length: 100 }),
  contactEmail: varchar("contact_email", { length: 255 }).notNull(),
  contactPhone: varchar("contact_phone", { length: 50 }),
  isPrimary: boolean("is_primary").default(false).notNull(),
  createdAt: timestamp("created_at").defaultNow().notNull(),
  updatedAt: timestamp("updated_at").defaultNow().notNull(),
});


export const vendorPossibleItems = pgTable("vendor_possible_items", {
  id: serial("id").primaryKey(),
  vendorId: integer("vendor_id").notNull().references(() => vendors.id),
  // itemId: integer("item_id"), // 별도 item 테이블 연동시
  itemCode: varchar("item_code", { length: 100 })
    .notNull()
    .references(() => items.itemCode, { onDelete: "cascade" }),
  createdAt: timestamp("created_at").defaultNow().notNull(),
  updatedAt: timestamp("updated_at").defaultNow().notNull(),
});


export const vendorPossibleMateirals = pgTable("vendor_possible_materials", {
  id: serial("id").primaryKey(),
  vendorId: integer("vendor_id").notNull().references(() => vendors.id),
  // itemId: integer("item_id"), // 별도 item 테이블 연동시
  itemCode: varchar("item_code", { length: 100 })
    .notNull()
    .references(() => materials.itemCode, { onDelete: "cascade" }),
  createdAt: timestamp("created_at").defaultNow().notNull(),
  updatedAt: timestamp("updated_at").defaultNow().notNull(),
});

export const vendorItemsView = pgView("vendor_items_view").as((qb) => {
  return qb
    .select({
      // vendorPossibleItems의 "id" -> "vendorItemId"
      vendorItemId: vendorPossibleItems.id,
      vendorId: vendorPossibleItems.vendorId,

      // items의 "id" -> "itemId"
      // itemId: items.id,
      itemName: items.itemName,
      itemCode: items.itemCode,
      description: items.description,

      createdAt: vendorPossibleItems.createdAt,
      updatedAt: vendorPossibleItems.updatedAt,
    })
    .from(vendorPossibleItems)
    .leftJoin(items, eq(vendorPossibleItems.itemCode, items.itemCode))
})

export const vendorMaterialsView = pgView("vendor_materials_view").as((qb) => {
  return qb
    .select({
      // vendorPossibleItems의 "id" -> "vendorItemId"
      vendorItemId: vendorPossibleMateirals.id,
      vendorId: vendorPossibleMateirals.vendorId,

      // items의 "id" -> "itemId"
      // itemId: items.id,
      itemName: materials.itemName,
      itemCode: materials.itemCode,
      description: materials.description,
      unitOfMeasure: materials.unitOfMeasure,
      steelType: materials.steelType,
      gradeMaterial: materials.gradeMaterial,

      createdAt: vendorPossibleMateirals.createdAt,
      updatedAt: vendorPossibleMateirals.updatedAt,
    })
    .from(vendorPossibleMateirals)
    .leftJoin(materials, eq(vendorPossibleMateirals.itemCode, materials.itemCode))
})

export const vendorAttachments = pgTable("vendor_attachments", {
  id: serial("id").primaryKey(),
  vendorId: integer("vendor_id").references(() => vendors.id),
  fileType: varchar("file_type", { length: 255 }),
  fileName: varchar("file_name", { length: 255 }).notNull(),
  filePath: varchar("file_path", { length: 1024 }).notNull(),
  attachmentType: varchar("attachment_type", {
    length: 50,
  }).default("GENERAL"),

  createdAt: timestamp("created_at").defaultNow().notNull(),
  updatedAt: timestamp("updated_at").defaultNow().notNull(),
});


export type Vendor = typeof vendors.$inferSelect
export type VendorContact = typeof vendorContacts.$inferSelect
export type VendorItem = typeof vendorPossibleItems.$inferSelect
export type VendorAttach = typeof vendorAttachments.$inferSelect

export type VendorWithAttachments = Vendor & {
  hasAttachments?: boolean;
  attachmentsList?: VendorAttach[];
}

export type VendorItemsView = typeof vendorItemsView.$inferSelect
export type VendorMaterialsView = typeof vendorMaterialsView.$inferSelect


export const vendorCandidates = pgTable("vendor_candidates", {
  id: serial("id").primaryKey(),
  companyName: varchar("company_name", { length: 255 }).notNull(),
  contactEmail: varchar("contact_email", { length: 255 }),
  contactPhone: varchar("contact_phone", { length: 50 }),
  
  taxId: varchar("tax_id", { length: 100 }).notNull(),
  address: text("address"),

  country: varchar("country", { length: 100 }),
  // 웹 크롤링 등으로 얻은 상태나 분류
  source: varchar("source", { length: 100 }),        // 수집 출처
  status: varchar("status", {
    length: 30,
    enum: [
      "COLLECTED",  // 단순 데이터 수집 완료
      "INVITED",    // 초청 메일 발송
      "DISCARDED",  // 불필요, 검토 후 배제됨
    ],
  })
    .notNull()
    .default("COLLECTED"),
  remark: text("remark"),
  items: text("items").notNull(),
  vendorId: integer("vendor_id")
    .references(() => vendors.id, { onDelete: "cascade" }),
  createdAt: timestamp("created_at").defaultNow().notNull(),
  updatedAt: timestamp("updated_at").defaultNow().notNull(),
});

export type VendorCandidates = typeof vendorCandidates.$inferSelect;


export const vendorDetailView = pgView("vendor_detail_view").as((qb) => {
  return qb
    .select({
      // 협력업체 기본 정보
      id: vendors.id,
      vendorName: vendors.vendorName,
      vendorCode: vendors.vendorCode,
      taxId: vendors.taxId,
      address: vendors.address,
      addressDetail: vendors.addressDetail,
      postalCode: vendors.postalCode,
      businessSize:vendors.businessSize,
      country: vendors.country,
      phone: vendors.phone,
      email: vendors.email,
      website: vendors.website,
      status: vendors.status,
      representativeName: vendors.representativeName,
      representativeBirth: vendors.representativeBirth,
      representativeEmail: vendors.representativeEmail,
      representativePhone: vendors.representativePhone,
      corporateRegistrationNumber: vendors.corporateRegistrationNumber,
      creditAgency: vendors.creditAgency,
      creditRating: vendors.creditRating,
      cashFlowRating: vendors.cashFlowRating,
      createdAt: vendors.createdAt,
      updatedAt: vendors.updatedAt,
      
      // 연락처 정보 (수정된 버전)
      contacts: sql<string>`
        (SELECT COALESCE(
          json_agg(
            json_build_object(
              'id', c.id,
              'contactName', c.contact_name,
              'contactPosition', c.contact_position,
              'contactEmail', c.contact_email,
              'contactPhone', c.contact_phone,
              'isPrimary', c.is_primary
            )
          ),
          '[]'::json
        )
        FROM vendor_contacts c
        WHERE c.vendor_id = vendors.id)
      `.as("contacts"),
      
      // 첨부파일 정보 (수정된 버전)
      attachments: sql<string>`
        (SELECT COALESCE(
          json_agg(
            json_build_object(
              'id', a.id,
              'fileName', a.file_name,
              'filePath', a.file_path,
              'attachmentType', a.attachment_type,
              'createdAt', a.created_at
            )
            ORDER BY a.attachment_type, a.created_at DESC
          ),
          '[]'::json
        )
        FROM vendor_attachments a
        WHERE a.vendor_id = vendors.id)
      `.as("attachments"),
      
      // 첨부파일 수 (수정된 버전)
      attachmentCount: sql<number>`
        (SELECT COUNT(*)
        FROM vendor_attachments a
        WHERE a.vendor_id = vendors.id)
      `.as("attachment_count"),
      
      // 연락처 수 (수정된 버전)
      contactCount: sql<number>`
        (SELECT COUNT(*) 
        FROM vendor_contacts c
        WHERE c.vendor_id = vendors.id)
      `.as("contact_count")
    })
    .from(vendors)
});

// 타입 정의
export type VendorDetailView = typeof vendorDetailView.$inferSelect;


// 관계 설정 (DrizzleORM을 사용한다고 가정)
export const vendorRelations = relations(vendors, ({ one }) => ({
  vendorType: one(vendorTypes, {
    fields: [vendors.vendorTypeId],
    references: [vendorTypes.id],
  }),
}));

export const vendorTypeRelations = relations(vendorTypes, ({ many }) => ({
  vendors: many(vendors),
}));

export type VendorTypes = typeof vendorTypes.$inferSelect;




export const vendorCandidatesWithVendorInfo = pgView("vendor_candidates_with_vendor_info").as((qb) => {
  return qb
    .select({
      // ----------------------------------------
      // 1) vendorCandidates 기본 필드
      id: vendorCandidates.id,
      companyName: vendorCandidates.companyName,
      contactEmail: vendorCandidates.contactEmail,
      contactPhone: vendorCandidates.contactPhone,
      taxId: vendorCandidates.taxId,
      address: vendorCandidates.address,
      country: vendorCandidates.country,
      source: vendorCandidates.source,
      status: vendorCandidates.status,
      items: vendorCandidates.items,
      remark: vendorCandidates.remark,
      // remark, items, vendorId 등 필요한 필드도 추가
      createdAt: vendorCandidates.createdAt,
      updatedAt: vendorCandidates.updatedAt,

      // ----------------------------------------
      // 2) vendors 조인해서 가져올 필드
      vendorName: vendors.vendorName,
      vendorCode: vendors.vendorCode,
      vendorCreatedAt: sql<Date>`${vendors.createdAt}`.as("vendor_created_at"),

      // ----------------------------------------
      // 3) 마지막 상태 변경 시각, 변경자 (action = 'status_change')
      lastStatusChangeAt: sql<Date>`(
        SELECT l2."created_at"
          FROM "vendor_candidate_logs" l2
         WHERE l2."vendor_candidate_id" = "vendor_candidates"."id"
           AND l2."action" = 'status_change'
         ORDER BY l2."created_at" DESC
         LIMIT 1
      )`.as("last_status_change_at"),

      lastStatusChangeBy: sql<string>`(
        SELECT u."name"
          FROM "users" u
          JOIN "vendor_candidate_logs" l3
            ON l3."user_id" = u."id"
         WHERE l3."vendor_candidate_id" = "vendor_candidates"."id"
           AND l3."action" = 'status_change'
         ORDER BY l3."created_at" DESC
         LIMIT 1
      )`.as("last_status_change_by"),

      // ----------------------------------------
      // 4) 마지막 초청(Invite) 시각, 초청자 (action = 'invite_sent')
      lastInvitationAt: sql<Date>`(
        SELECT l4."created_at"
          FROM "vendor_candidate_logs" l4
         WHERE l4."vendor_candidate_id" = "vendor_candidates"."id"
           AND l4."action" = 'invite_sent'
         ORDER BY l4."created_at" DESC
         LIMIT 1
      )`.as("last_invitation_at"),

      lastInvitationBy: sql<string>`(
        SELECT u2."name"
          FROM "users" u2
          JOIN "vendor_candidate_logs" l5
            ON l5."user_id" = u2."id"
         WHERE l5."vendor_candidate_id" = "vendor_candidates"."id"
           AND l5."action" = 'invite_sent'
         ORDER BY l5."created_at" DESC
         LIMIT 1
      )`.as("last_invitation_by"),
    })
    .from(vendorCandidates)
    .leftJoin(vendors, eq(vendorCandidates.vendorId, vendors.id));
});

export type VendorCandidatesWithVendorInfo = typeof vendorCandidatesWithVendorInfo.$inferSelect;


export const vendorsWithTypesView = pgView("vendors_with_types").as((qb) => {
  return qb
    .select({
      // Vendor fields
      id: sql<number>`${vendors.id}`.as("id"),
      vendorName: sql<string>`${vendors.vendorName}`.as("vendor_name"),
      vendorCode: sql<string>`${vendors.vendorCode}`.as("vendor_code"),
      taxId: sql<string>`${vendors.taxId}`.as("tax_id"),
      address: sql<string>`${vendors.address}`.as("address"),
      addressDetail: sql<string>`${vendors.addressDetail}`.as("address_detail"),
      postalCode: sql<string>`${vendors.postalCode}`.as("postal_code"),
      country: sql<string>`${vendors.country}`.as("country"),
      phone: sql<string>`${vendors.phone}`.as("phone"),
      email: sql<string>`${vendors.email}`.as("email"),
      businessSize: sql<string>`${vendors.businessSize}`.as("business_size"),
      website: sql<string>`${vendors.website}`.as("website"),
      status: sql<string>`${vendors.status}`.as("status"),
      vendorTypeId: sql<number>`${vendors.vendorTypeId}`.as("vendor_type_id"),
      representativeName: sql<string>`${vendors.representativeName}`.as("representative_name"),
      representativeBirth: sql<string>`${vendors.representativeBirth}`.as("representative_birth"),
      representativeEmail: sql<string>`${vendors.representativeEmail}`.as("representative_email"),
      representativePhone: sql<string>`${vendors.representativePhone}`.as("representative_phone"),
      corporateRegistrationNumber: sql<string>`${vendors.corporateRegistrationNumber}`.as("corporate_registration_number"),
      items: sql<string>`${vendors.items}`.as("items"),
      creditAgency: sql<string>`${vendors.creditAgency}`.as("credit_agency"),
      creditRating: sql<string>`${vendors.creditRating}`.as("credit_rating"),
      cashFlowRating: sql<string>`${vendors.cashFlowRating}`.as("cash_flow_rating"),
      createdAt: sql<Date>`${vendors.createdAt}`.as("created_at"),
      updatedAt: sql<Date>`${vendors.updatedAt}`.as("updated_at"),

      // Vendor type fields
      vendorTypeName: sql<string>`${vendorTypes.nameKo}`.as("vendor_type_name"),
      vendorTypeNameEn: sql<string>`${vendorTypes.nameEn}`.as("vendor_type_name_en"),
      vendorTypeCode: sql<string>`${vendorTypes.code}`.as("vendor_type_code"),

      // Computed vendor category field
      vendorCategory: sql<string>`
        CASE
          WHEN ${vendors.status} = 'ACTIVE' THEN '정규업체'
          WHEN ${vendors.status} IN ('INACTIVE', 'BLACKLISTED', 'REJECTED') THEN ''
          ELSE '잠재업체'
        END
      `.as("vendor_category")
    })
    .from(vendors)
    .leftJoin(
      vendorTypes,
      sql`${vendors.vendorTypeId} = ${vendorTypes.id}`
    );
});


// You can also create interfaces for the view
export type VendorWithType = typeof vendorsWithTypesView.$inferSelect;