summaryrefslogtreecommitdiff
path: root/db/schema/risks/risks.ts
blob: 0a4366d66efb89bd69b67f401e86706220ed5407 (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
/* IMPORT */
import {
  boolean,
  integer,
  pgSchema,
  serial,
  text,
  timestamp,
  varchar,
} from 'drizzle-orm/pg-core';
import { eq, relations, sql } from 'drizzle-orm';
import { users } from '../users';
import { vendors } from '../vendors';

// ----------------------------------------------------------------------------------------------------

/* TABLE SCHEMATA */
const risksSchema = pgSchema('risks');
const riskEvents = risksSchema.table('risk_events', {
  id: serial('id').primaryKey(),
  vendorId: integer('vendor_id')
    .notNull()
    .references(() => vendors.id, { onDelete: 'cascade' }),
  provider: varchar('provider', { length: 128 }).notNull(),
  eventType: varchar('event_type', { length: 50 }).notNull(),
  content: text('content'),
  eventStatus: boolean('event_status').default(true).notNull(),
  managerId: integer('manager_id')
    .references(() => users.id, { onDelete: 'set null' }),
  adminComment: text('admin_comment'),
  occuredAt: timestamp('occurred_at').defaultNow().notNull(),
  createdAt: timestamp('created_at').defaultNow().notNull(),
  updatedAt: timestamp('updated_at').defaultNow().notNull(),
  createdBy: integer('created_by')
    .references(() => users.id, { onDelete: 'set null' }),
  updatedBy: integer('updated_by')
    .references(() => users.id, { onDelete: 'set null' }),
});

// ----------------------------------------------------------------------------------------------------

/* VIEWS */
const risksView = risksSchema.view('risks_view').as((qb) => {

  return qb
    .select({
      id: riskEvents.id,
      eventType: riskEvents.eventType,
      vendorId: riskEvents.vendorId,
      vendorCode: vendors.vendorCode,
      vendorName: vendors.vendorName,
      businessNumber: vendors.taxId,
      provider: riskEvents.provider,
      content: riskEvents.content,
      prevRatingTotal: sql`
        CASE 
          WHEN ${riskEvents.eventType} = '종합등급' THEN 
            COALESCE((
              SELECT content 
              FROM ${risksSchema}.risk_events re2 
              WHERE re2.vendor_id = ${riskEvents.vendorId} 
                AND re2.event_type = '종합등급' 
                AND re2.occurred_at < ${riskEvents.occuredAt}
              ORDER BY re2.occurred_at DESC 
              LIMIT 1
            ), '-')
          ELSE 
            COALESCE((
              SELECT content 
              FROM ${risksSchema}.risk_events re2 
              WHERE re2.vendor_id = ${riskEvents.vendorId} 
                AND re2.event_type = '종합등급' 
                AND re2.occurred_at <= ${riskEvents.occuredAt}
              ORDER BY re2.occurred_at DESC 
              LIMIT 1
            ), '-')
        END
      `.as('prev_rating_total'),
      curRatingTotal: sql`
        CASE 
          WHEN ${riskEvents.eventType} = '종합등급' THEN 
            ${riskEvents.content}
          ELSE 
            COALESCE((
              SELECT content 
              FROM ${risksSchema}.risk_events re2 
              WHERE re2.vendor_id = ${riskEvents.vendorId} 
                AND re2.event_type = '종합등급' 
                AND re2.occurred_at <= ${riskEvents.occuredAt}
              ORDER BY re2.occurred_at DESC 
              LIMIT 1
            ), '-')
        END
      `.as('cur_rating_total'),
      prevRatingCredit: sql`
        CASE 
          WHEN ${riskEvents.eventType} = '신용등급' THEN 
            COALESCE((
              SELECT content 
              FROM ${risksSchema}.risk_events re2 
              WHERE re2.vendor_id = ${riskEvents.vendorId} 
                AND re2.event_type = '신용등급' 
                AND re2.occurred_at < ${riskEvents.occuredAt}
              ORDER BY re2.occurred_at DESC 
              LIMIT 1
            ), '-')
          ELSE 
            COALESCE((
              SELECT content 
              FROM ${risksSchema}.risk_events re2 
              WHERE re2.vendor_id = ${riskEvents.vendorId} 
                AND re2.event_type = '신용등급' 
                AND re2.occurred_at <= ${riskEvents.occuredAt}
              ORDER BY re2.occurred_at DESC 
              LIMIT 1
            ), '-')
        END
      `.as('prev_rating_credit'),
      curRatingCredit: sql`
        CASE 
          WHEN ${riskEvents.eventType} = '신용등급' THEN 
            ${riskEvents.content}
          ELSE 
            COALESCE((
              SELECT content 
              FROM ${risksSchema}.risk_events re2 
              WHERE re2.vendor_id = ${riskEvents.vendorId} 
                AND re2.event_type = '신용등급' 
                AND re2.occurred_at <= ${riskEvents.occuredAt}
              ORDER BY re2.occurred_at DESC 
              LIMIT 1
            ), '-')
        END
      `.as('cur_rating_credit'),
      prevRatingCashflow: sql`
        CASE 
          WHEN ${riskEvents.eventType} = '현금흐름등급' THEN 
            COALESCE((
              SELECT content 
              FROM ${risksSchema}.risk_events re2 
              WHERE re2.vendor_id = ${riskEvents.vendorId} 
                AND re2.event_type = '현금흐름등급' 
                AND re2.occurred_at < ${riskEvents.occuredAt}
              ORDER BY re2.occurred_at DESC 
              LIMIT 1
            ), '-')
          ELSE 
            COALESCE((
              SELECT content 
              FROM ${risksSchema}.risk_events re2 
              WHERE re2.vendor_id = ${riskEvents.vendorId} 
                AND re2.event_type = '현금흐름등급' 
                AND re2.occurred_at <= ${riskEvents.occuredAt}
              ORDER BY re2.occurred_at DESC 
              LIMIT 1
            ), '-')
        END
      `.as('prev_rating_cashflow'),
      curRatingCashflow: sql`
        CASE 
          WHEN ${riskEvents.eventType} = '현금흐름등급' THEN 
            ${riskEvents.content}
          ELSE 
            COALESCE((
              SELECT content 
              FROM ${risksSchema}.risk_events re2 
              WHERE re2.vendor_id = ${riskEvents.vendorId} 
                AND re2.event_type = '현금흐름등급' 
                AND re2.occurred_at <= ${riskEvents.occuredAt}
              ORDER BY re2.occurred_at DESC 
              LIMIT 1
            ), '-')
        END
      `.as('cur_rating_cashflow'),
      prevRatingWatch: sql`
        CASE 
          WHEN ${riskEvents.eventType} = 'WATCH등급' THEN 
            COALESCE((
              SELECT content 
              FROM ${risksSchema}.risk_events re2 
              WHERE re2.vendor_id = ${riskEvents.vendorId} 
                AND re2.event_type = 'WATCH등급' 
                AND re2.occurred_at < ${riskEvents.occuredAt}
              ORDER BY re2.occurred_at DESC 
              LIMIT 1
            ), '-')
          ELSE 
            COALESCE((
              SELECT content 
              FROM ${risksSchema}.risk_events re2 
              WHERE re2.vendor_id = ${riskEvents.vendorId} 
                AND re2.event_type = 'WATCH등급' 
                AND re2.occurred_at <= ${riskEvents.occuredAt}
              ORDER BY re2.occurred_at DESC 
              LIMIT 1
            ), '-')
        END
      `.as('prev_rating_watch'),
      curRatingWatch: sql`
        CASE 
          WHEN ${riskEvents.eventType} = 'WATCH등급' THEN 
            ${riskEvents.content}
          ELSE 
            COALESCE((
              SELECT content 
              FROM ${risksSchema}.risk_events re2 
              WHERE re2.vendor_id = ${riskEvents.vendorId} 
                AND re2.event_type = 'WATCH등급' 
                AND re2.occurred_at <= ${riskEvents.occuredAt}
              ORDER BY re2.occurred_at DESC 
              LIMIT 1
            ), '-')
        END
      `.as('cur_rating_watch'),
      eventStatus: riskEvents.eventStatus,
      managerId: riskEvents.managerId,
      managerName: users.name,
      adminComment: riskEvents.adminComment,
      occuredAt: riskEvents.occuredAt,
    })
    .from(riskEvents)
    .leftJoin(vendors, eq(vendors.id, riskEvents.vendorId))
    .leftJoin(users, eq(users.id, riskEvents.managerId))
});

// ----------------------------------------------------------------------------------------------------

/* RELATIONS */
const riskEventsRelations = relations(riskEvents, ({ one }) => ({
  vendor: one(vendors, {
    fields: [riskEvents.vendorId],
    references: [vendors.id],
  }),
  manager: one(users, {
    fields: [riskEvents.managerId],
    references: [users.id],
  }),
  createdByUser: one(users, {
    fields: [riskEvents.createdBy],
    references: [users.id],
  }),
  updatedByUser: one(users, {
    fields: [riskEvents.updatedBy],
    references: [users.id],
  }),
}));

// ----------------------------------------------------------------------------------------------------

/* TYPES */
type RiskEvents = typeof riskEvents.$inferSelect;
type NewRiskEvents = typeof riskEvents.$inferInsert;
type RisksView = typeof risksView.$inferSelect;

// ----------------------------------------------------------------------------------------------------

/* Export */
export {
  risksSchema,
  risksView,
  riskEvents,
  riskEventsRelations,
  type NewRiskEvents,
  type RiskEvents,
  type RisksView,
};