summaryrefslogtreecommitdiff
path: root/db/migrations/0269_remarkable_shard.sql
blob: 2901df0f132160a2da6b2d5255be72a947d9e229 (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
CREATE VIEW "public"."bidding_list_view" AS (select "biddings"."id", "biddings"."bidding_number", "biddings"."revision", "biddings"."project_name", "biddings"."item_name", "biddings"."title", "biddings"."description", "biddings"."content", "biddings"."contract_type", "biddings"."bidding_type", "biddings"."award_count", "biddings"."contract_period", "biddings"."pre_quote_date", "biddings"."bidding_registration_date", "biddings"."submission_start_date", "biddings"."submission_end_date", "biddings"."evaluation_date", "biddings"."has_specification_meeting", "biddings"."has_pr_document", "biddings"."pr_number", "biddings"."currency", "biddings"."budget", "biddings"."target_price", "biddings"."final_bid_price", "biddings"."status", "biddings"."is_public", "biddings"."manager_name", "biddings"."manager_email", "biddings"."manager_phone", "biddings"."remarks", "biddings"."created_by", "biddings"."created_at", "biddings"."updated_at", "biddings"."updated_by", "specification_meetings"."id" IS NOT NULL as "has_specification_meeting_details", "specification_meetings"."meeting_date", "specification_meetings"."location", "specification_meetings"."contact_person", "specification_meetings"."is_required", 
        COALESCE((
          SELECT count(*) 
          FROM pr_documents 
          WHERE bidding_id = "biddings"."id"
        ), 0)
       as "pr_document_count", 
        (
          SELECT array_agg(document_name ORDER BY registered_at DESC)
          FROM pr_documents 
          WHERE bidding_id = "biddings"."id"
          LIMIT 5
        )
       as "pr_document_names", 
        COALESCE((
          SELECT count(*) 
          FROM bidding_companies 
          WHERE bidding_id = "biddings"."id"
        ), 0)
       as "participant_expected", 
        COALESCE((
          SELECT count(*) 
          FROM bidding_companies 
          WHERE bidding_id = "biddings"."id" 
          AND invitation_status = 'submitted'
        ), 0)
       as "participant_participated", 
        COALESCE((
          SELECT count(*) 
          FROM bidding_companies 
          WHERE bidding_id = "biddings"."id" 
          AND invitation_status = 'declined'
        ), 0)
       as "participant_declined", 
        COALESCE((
          SELECT count(*) 
          FROM bidding_companies 
          WHERE bidding_id = "biddings"."id" 
          AND invitation_status IN ('pending', 'sent')
        ), 0)
       as "participant_pending", 
        COALESCE((
          SELECT count(*) 
          FROM bidding_companies 
          WHERE bidding_id = "biddings"."id" 
          AND invitation_status = 'accepted'
        ), 0)
       as "participant_accepted", 
        CASE 
          WHEN (
            SELECT count(*) 
            FROM bidding_companies 
            WHERE bidding_id = "biddings"."id"
          ) > 0 
          THEN ROUND(
            (
              SELECT count(*)::decimal 
              FROM bidding_companies 
              WHERE bidding_id = "biddings"."id" 
              AND invitation_status = 'submitted'
            ) / (
              SELECT count(*)::decimal 
              FROM bidding_companies 
              WHERE bidding_id = "biddings"."id"
            ) * 100, 1
          )
          ELSE 0 
        END
       as "participation_rate", 
        (
          SELECT AVG(pre_quote_amount) 
          FROM bidding_companies 
          WHERE bidding_id = "biddings"."id" 
          AND pre_quote_amount IS NOT NULL
        )
       as "avg_pre_quote_amount", 
        (
          SELECT MIN(pre_quote_amount) 
          FROM bidding_companies 
          WHERE bidding_id = "biddings"."id" 
          AND pre_quote_amount IS NOT NULL
        )
       as "min_pre_quote_amount", 
        (
          SELECT MAX(pre_quote_amount) 
          FROM bidding_companies 
          WHERE bidding_id = "biddings"."id" 
          AND pre_quote_amount IS NOT NULL
        )
       as "max_pre_quote_amount", 
        (
          SELECT AVG(final_quote_amount) 
          FROM bidding_companies 
          WHERE bidding_id = "biddings"."id" 
          AND final_quote_amount IS NOT NULL
        )
       as "avg_final_quote_amount", 
        (
          SELECT MIN(final_quote_amount) 
          FROM bidding_companies 
          WHERE bidding_id = "biddings"."id" 
          AND final_quote_amount IS NOT NULL
        )
       as "min_final_quote_amount", 
        (
          SELECT MAX(final_quote_amount) 
          FROM bidding_companies 
          WHERE bidding_id = "biddings"."id" 
          AND final_quote_amount IS NOT NULL
        )
       as "max_final_quote_amount", 
        COALESCE((
          SELECT count(*) 
          FROM bidding_companies 
          WHERE bidding_id = "biddings"."id" 
          AND is_pre_quote_selected = true
        ), 0)
       as "selected_for_final_bid_count", 
        COALESCE((
          SELECT count(*) 
          FROM bidding_companies 
          WHERE bidding_id = "biddings"."id" 
          AND is_winner = true
        ), 0)
       as "winner_count", 
        (
          SELECT array_agg(v.vendor_name ORDER BY v.vendor_name)
          FROM bidding_companies bc
          JOIN vendors v ON bc.company_id = v.id
          WHERE bc.bidding_id = "biddings"."id" 
          AND bc.is_winner = true
        )
       as "winner_company_names", 
        CASE 
          WHEN "biddings"."submission_start_date" IS NULL OR "biddings"."submission_end_date" IS NULL 
          THEN 'not_scheduled'
          WHEN NOW() < "biddings"."submission_start_date" 
          THEN 'scheduled'
          WHEN NOW() BETWEEN "biddings"."submission_start_date" AND "biddings"."submission_end_date" 
          THEN 'active'
          WHEN NOW() > "biddings"."submission_end_date" 
          THEN 'closed'
          ELSE 'unknown'
        END
       as "submission_status", 
        CASE 
          WHEN "biddings"."submission_end_date" IS NOT NULL 
          AND NOW() < "biddings"."submission_end_date" 
          THEN EXTRACT(DAYS FROM ("biddings"."submission_end_date" - NOW()))::integer
          ELSE NULL 
        END
       as "days_until_deadline", 
        CASE 
          WHEN "biddings"."submission_start_date" IS NOT NULL 
          AND NOW() < "biddings"."submission_start_date" 
          THEN EXTRACT(DAYS FROM ("biddings"."submission_start_date" - NOW()))::integer
          ELSE NULL 
        END
       as "days_until_start", 
        CASE 
          WHEN "biddings"."budget" IS NOT NULL AND "biddings"."budget" > 0
          AND (
            SELECT MIN(final_quote_amount) 
            FROM bidding_companies 
            WHERE bidding_id = "biddings"."id" 
            AND final_quote_amount IS NOT NULL
          ) IS NOT NULL
          THEN ROUND(
            (
              SELECT MIN(final_quote_amount) 
              FROM bidding_companies 
              WHERE bidding_id = "biddings"."id" 
              AND final_quote_amount IS NOT NULL
            ) / "biddings"."budget" * 100, 1
          )
          ELSE NULL 
        END
       as "budget_efficiency_rate", 
        CASE 
          WHEN "biddings"."target_price" IS NOT NULL AND "biddings"."target_price" > 0
          AND (
            SELECT MIN(final_quote_amount) 
            FROM bidding_companies 
            WHERE bidding_id = "biddings"."id" 
            AND final_quote_amount IS NOT NULL
          ) IS NOT NULL
          THEN ROUND(
            (
              SELECT MIN(final_quote_amount) 
              FROM bidding_companies 
              WHERE bidding_id = "biddings"."id" 
              AND final_quote_amount IS NOT NULL
            ) / "biddings"."target_price" * 100, 1
          )
          ELSE NULL 
        END
       as "target_price_efficiency_rate", 
        CASE "biddings"."status"
          WHEN 'bidding_generated' THEN 10
          WHEN 'request_for_quotation' THEN 20
          WHEN 'received_quotation' THEN 40
          WHEN 'set_target_price' THEN 60
          WHEN 'bidding_opened' THEN 70
          WHEN 'bidding_closed' THEN 80
          WHEN 'evaluation_of_bidding' THEN 90
          WHEN 'vendor_selected' THEN 100
          WHEN 'bidding_disposal' THEN 0
          ELSE 0
        END
       as "progress_score", 
        GREATEST(
          "biddings"."updated_at",
          COALESCE((
            SELECT MAX(updated_at) 
            FROM bidding_companies 
            WHERE bidding_id = "biddings"."id"
          ), "biddings"."updated_at")
        )
       as "last_activity_date" from "biddings" left join "specification_meetings" on "biddings"."id" = "specification_meetings"."bidding_id");